Skip to content

Commit

Permalink
fix: remove constraint before alter foreign keys (#8795)
Browse files Browse the repository at this point in the history
  • Loading branch information
lext-7 authored and sushantdhiman committed Jan 8, 2018
1 parent d98d8bd commit bb2d0bd
Show file tree
Hide file tree
Showing 15 changed files with 351 additions and 48 deletions.
63 changes: 40 additions & 23 deletions lib/dialects/mssql/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -646,40 +646,57 @@ const QueryGenerator = {
return '[' + identifier.replace(/[\[\]']+/g, '') + ']';
},

getForeignKeysQuery(table) {
/**
* Generate common SQL prefix for ForeignKeysQuery.
* @returns {String}
*/
_getForeignKeysQueryPrefix(catalogName) {
return 'SELECT ' +
'constraint_name = OBJ.NAME, ' +
'constraintName = OBJ.NAME, ' +
(catalogName ? `constraintCatalog = '${catalogName}', ` : '') +
'constraintSchema = SCHEMA_NAME(OBJ.SCHEMA_ID), ' +
'tableName = TB.NAME, ' +
'tableSchema = SCHEMA_NAME(TB.SCHEMA_ID), ' +
(catalogName ? `tableCatalog = '${catalogName}', ` : '') +
'columnName = COL.NAME, ' +
'referencedTableSchema = SCHEMA_NAME(RTB.SCHEMA_ID), ' +
(catalogName ? `referencedCatalog = '${catalogName}', ` : '') +
'referencedTableName = RTB.NAME, ' +
'referencedColumnName = RCOL.NAME ' +
'FROM SYS.FOREIGN_KEY_COLUMNS FKC ' +
'INNER JOIN SYS.OBJECTS OBJ ON OBJ.OBJECT_ID = FKC.CONSTRAINT_OBJECT_ID ' +
'INNER JOIN SYS.TABLES TB ON TB.OBJECT_ID = FKC.PARENT_OBJECT_ID ' +
'INNER JOIN SYS.COLUMNS COL ON COL.COLUMN_ID = PARENT_COLUMN_ID AND COL.OBJECT_ID = TB.OBJECT_ID ' +
'INNER JOIN SYS.TABLES RTB ON RTB.OBJECT_ID = FKC.REFERENCED_OBJECT_ID ' +
'INNER JOIN SYS.COLUMNS RCOL ON RCOL.COLUMN_ID = REFERENCED_COLUMN_ID AND RCOL.OBJECT_ID = RTB.OBJECT_ID';
},

/**
* Generates an SQL query that returns all foreign keys details of a table.
* @param {Stirng|Object} table
* @param {String} catalogName database name
* @returns {String}
*/
getForeignKeysQuery(table, catalogName) {
const tableName = table.tableName || table;
let sql = [
'SELECT',
'constraint_name = C.CONSTRAINT_NAME',
'FROM',
'INFORMATION_SCHEMA.TABLE_CONSTRAINTS C',
"WHERE C.CONSTRAINT_TYPE = 'FOREIGN KEY'",
'AND C.TABLE_NAME =', wrapSingleQuote(tableName)
].join(' ');
let sql = this._getForeignKeysQueryPrefix(catalogName) +
' WHERE TB.NAME =' + wrapSingleQuote(tableName);

if (table.schema) {
sql += ' AND C.TABLE_SCHEMA =' + wrapSingleQuote(table.schema);
sql += ' AND SCHEMA_NAME(TB.SCHEMA_ID) =' + wrapSingleQuote(table.schema);
}

return sql;
},

getForeignKeyQuery(table, attributeName) {
const tableName = table.tableName || table;
let sql = [
'SELECT',
'constraint_name = TC.CONSTRAINT_NAME',
'FROM',
'INFORMATION_SCHEMA.TABLE_CONSTRAINTS TC',
'JOIN INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE CCU',
'ON TC.CONSTRAINT_NAME = CCU.CONSTRAINT_NAME',
"WHERE TC.CONSTRAINT_TYPE = 'FOREIGN KEY'",
'AND TC.TABLE_NAME =', wrapSingleQuote(tableName),
'AND CCU.COLUMN_NAME =', wrapSingleQuote(attributeName)
].join(' ');
let sql = this._getForeignKeysQueryPrefix() +
' WHERE TB.NAME =' + wrapSingleQuote(tableName) +
' AND COL.NAME =' + wrapSingleQuote(attributeName);

if (table.schema) {
sql += ' AND TC.TABLE_SCHEMA =' + wrapSingleQuote(table.schema);
sql += ' AND SCHEMA_NAME(TB.SCHEMA_ID) =' + wrapSingleQuote(table.schema);
}

return sql;
Expand Down
45 changes: 37 additions & 8 deletions lib/dialects/mysql/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -274,7 +274,10 @@ const QueryGenerator = {
return 'SHOW INDEX FROM ' + this.quoteTable(tableName) + ((options || {}).database ? ' FROM `' + options.database + '`' : '');
},

showConstraintsQuery(tableName, constraintName) {
showConstraintsQuery(table, constraintName) {
const tableName = table.tableName || table;
const schemaName = table.schema;

let sql = [
'SELECT CONSTRAINT_CATALOG AS constraintCatalog,',
'CONSTRAINT_NAME AS constraintName,',
Expand All @@ -290,6 +293,10 @@ const QueryGenerator = {
sql += ` AND constraint_name = '${constraintName}'`;
}

if (schemaName) {
sql += ` AND TABLE_SCHEMA = '${schemaName}'`;
}

return sql + ';';
},

Expand Down Expand Up @@ -473,6 +480,27 @@ const QueryGenerator = {
return `(${quotedColumn}->>'${pathStr}')`;
},

/**
* Generates fields for getForeignKeysQuery
* @returns {String} fields
* @private
*/
_getForeignKeysQueryFields() {
return [
'CONSTRAINT_NAME as constraint_name',
'CONSTRAINT_NAME as constraintName',
'CONSTRAINT_SCHEMA as constraintSchema',
'CONSTRAINT_SCHEMA as constraintCatalog',
'TABLE_NAME as tableName',
'TABLE_SCHEMA as tableSchema',
'TABLE_SCHEMA as tableCatalog',
'COLUMN_NAME as columnName',
'REFERENCED_TABLE_SCHEMA as referencedTableSchema',
'REFERENCED_TABLE_SCHEMA as referencedTableCatalog',
'REFERENCED_TABLE_NAME as referencedTableName',
'REFERENCED_COLUMN_NAME as referencedColumnName',
].join(',');
},

/**
* Generates an SQL query that returns all foreign keys of a table.
Expand All @@ -483,8 +511,8 @@ const QueryGenerator = {
* @private
*/
getForeignKeysQuery(tableName, schemaName) {
return "SELECT CONSTRAINT_NAME as constraint_name FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE where TABLE_NAME = '" + tableName + /* jshint ignore: line */
"' AND CONSTRAINT_NAME!='PRIMARY' AND CONSTRAINT_SCHEMA='" + schemaName + "' AND REFERENCED_TABLE_NAME IS NOT NULL;"; /* jshint ignore: line */
return 'SELECT ' + this._getForeignKeysQueryFields() + ' FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE where TABLE_NAME = \'' + tableName + /* jshint ignore: line */
'\' AND CONSTRAINT_NAME!=\'PRIMARY\' AND CONSTRAINT_SCHEMA=\'' + schemaName + '\' AND REFERENCED_TABLE_NAME IS NOT NULL;'; /* jshint ignore: line */
},

/**
Expand All @@ -496,15 +524,16 @@ const QueryGenerator = {
* @private
*/
getForeignKeyQuery(table, columnName) {
let tableName = table.tableName || table;
if (table.schema) {
tableName = table.schema + '.' + tableName;
}
return 'SELECT CONSTRAINT_NAME as constraint_name'
const tableName = table.tableName || table;
const schemaName = table.schema;

return 'SELECT ' + this._getForeignKeysQueryFields()
+ ' FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE'
+ ' WHERE (REFERENCED_TABLE_NAME = ' + wrapSingleQuote(tableName)
+ (schemaName ? ' AND REFERENCED_TABLE_SCHEMA = ' + wrapSingleQuote(schemaName): '')
+ ' AND REFERENCED_COLUMN_NAME = ' + wrapSingleQuote(columnName)
+ ') OR (TABLE_NAME = ' + wrapSingleQuote(tableName)
+ (schemaName ? ' AND TABLE_SCHEMA = ' + wrapSingleQuote(schemaName): '')
+ ' AND COLUMN_NAME = ' + wrapSingleQuote(columnName)
+ ' AND REFERENCED_TABLE_NAME IS NOT NULL'
+ ')';
Expand Down
16 changes: 11 additions & 5 deletions lib/dialects/mysql/query-interface.js
Original file line number Diff line number Diff line change
Expand Up @@ -26,7 +26,10 @@ function removeColumn(tableName, columnName, options) {
options = options || {};

return this.sequelize.query(
this.QueryGenerator.getForeignKeyQuery(tableName, columnName),
this.QueryGenerator.getForeignKeyQuery(tableName.tableName ? tableName : {
tableName,
schema: this.sequelize.config.database
}, columnName),
_.assign({ raw: true }, options)
)
.spread(results => {
Expand All @@ -35,10 +38,10 @@ function removeColumn(tableName, columnName, options) {
// No foreign key constraints found, so we can remove the column
return;
}
return this.sequelize.query(
this.QueryGenerator.dropForeignKeyQuery(tableName, results[0].constraint_name),
return this.sequelize.Promise.map(results, constraint => this.sequelize.query(
this.QueryGenerator.dropForeignKeyQuery(tableName, constraint.constraint_name),
_.assign({ raw: true }, options)
);
));
})
.then(() => this.sequelize.query(
this.QueryGenerator.removeColumnQuery(tableName, columnName),
Expand All @@ -48,7 +51,10 @@ function removeColumn(tableName, columnName, options) {


function removeConstraint(tableName, constraintName, options) {
const sql = this.QueryGenerator.showConstraintsQuery(tableName, constraintName);
const sql = this.QueryGenerator.showConstraintsQuery(tableName.tableName ? tableName : {
tableName,
schema: this.sequelize.config.database
}, constraintName);

return this.sequelize.query(sql, Object.assign({}, options, { type: this.sequelize.QueryTypes.SHOWCONSTRAINTS }))
.then(constraints => {
Expand Down
47 changes: 47 additions & 0 deletions lib/dialects/postgres/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -880,6 +880,53 @@ const QueryGenerator = {
`WHERE r.conrelid = (SELECT oid FROM pg_class WHERE relname = '${tableName}' LIMIT 1) AND r.contype = 'f' ORDER BY 1;`;
},

/**
* Generate common SQL prefix for getForeignKeyReferencesQuery.
* @returns {String}
*/
_getForeignKeyReferencesQueryPrefix() {
return 'SELECT ' +
'DISTINCT tc.constraint_name as constraint_name, ' +
'tc.constraint_schema as constraint_schema, ' +
'tc.constraint_catalog as constraint_catalog, ' +
'tc.table_name as table_name,' +
'tc.table_schema as table_schema,' +
'tc.table_catalog as table_catalog,' +
'kcu.column_name as column_name,' +
'ccu.table_schema AS referenced_table_schema,' +
'ccu.table_catalog AS referenced_table_catalog,' +
'ccu.table_name AS referenced_table_name,' +
'ccu.column_name AS referenced_column_name ' +
'FROM information_schema.table_constraints AS tc ' +
'JOIN information_schema.key_column_usage AS kcu ' +
'ON tc.constraint_name = kcu.constraint_name ' +
'JOIN information_schema.constraint_column_usage AS ccu ' +
'ON ccu.constraint_name = tc.constraint_name ';
},

/**
* Generates an SQL query that returns all foreign keys details of a table.
*
* As for getForeignKeysQuery is not compatible with getForeignKeyReferencesQuery, so add a new function.
* @param {String} tableName
* @param {String} catalogName
* @param {String} schemaName
*/
getForeignKeyReferencesQuery(tableName, catalogName, schemaName) {
return this._getForeignKeyReferencesQueryPrefix() +
`WHERE constraint_type = 'FOREIGN KEY' AND tc.table_name = '${tableName}'` +
(catalogName ? ` AND tc.table_catalog = '${catalogName}'` : '') +
(schemaName ? ` AND tc.table_schema = '${schemaName}'` : '');
},

getForeignKeyReferenceQuery(table, columnName) {
const tableName = table.tableName || table;
const schema = table.schema;
return this._getForeignKeyReferencesQueryPrefix() +
`WHERE constraint_type = 'FOREIGN KEY' AND tc.table_name='${tableName}' AND kcu.column_name = '${columnName}'` +
(schema ? ` AND tc.table_schema = '${schema}'` : '');
},

/**
* Generates an SQL query that removes a foreign key from a table.
*
Expand Down
3 changes: 2 additions & 1 deletion lib/dialects/sqlite/query-generator.js
Original file line number Diff line number Diff line change
Expand Up @@ -402,7 +402,8 @@ const QueryGenerator = {
const quotedBackupTableName = this.quoteTable(backupTableName);
const attributeNames = Object.keys(attributes).map(attr => this.quoteIdentifier(attr)).join(', ');

return this.createTableQuery(backupTableName, attributes).replace('CREATE TABLE', 'CREATE TEMPORARY TABLE')
// Temporary table cannot work for foreign keys.
return this.createTableQuery(backupTableName, attributes)
+ `INSERT INTO ${quotedBackupTableName} SELECT ${attributeNames} FROM ${quotedTableName};`
+ `DROP TABLE ${quotedTableName};`
+ this.createTableQuery(tableName, attributes)
Expand Down
24 changes: 24 additions & 0 deletions lib/dialects/sqlite/query-interface.js
Original file line number Diff line number Diff line change
Expand Up @@ -166,3 +166,27 @@ function addConstraint(tableName, options) {
});
}
exports.addConstraint = addConstraint;

/**
*
* @param {String} tableName
* @param {Object} options Query Options
* @returns {Promise}
*/
function getForeignKeyReferencesForTable(tableName, options) {
const database = this.sequelize.config.database;
const query = this.QueryGenerator.getForeignKeysQuery(tableName, database);
return this.sequelize.query(query, options)
.then(result => {
return result.map(row => ({
tableName,
columnName: row.from,
referencedTableName: row.table,
referencedColumnName: row.to,
tableCatalog: database,
referencedTableCatalog: database
}));
});
}

exports.getForeignKeyReferencesForTable = getForeignKeyReferencesForTable;
39 changes: 35 additions & 4 deletions lib/model.js
Original file line number Diff line number Diff line change
Expand Up @@ -1122,18 +1122,49 @@ class Model {
.then(() => this.QueryInterface.createTable(this.getTableName(options), attributes, options, this))
.then(() => {
if (options.alter) {
return this.QueryInterface.describeTable(this.getTableName(options))
.then(columns => {
return Promise.all([
this.QueryInterface.describeTable(this.getTableName(options)),
this.QueryInterface.getForeignKeyReferencesForTable(this.getTableName(options))
])
.then(tableInfos => {
const columns = tableInfos[0];
// Use for alter foreign keys
const foreignKeyReferences = tableInfos[1];

const changes = []; // array of promises to run
const removedConstraints = {};

_.each(attributes, (columnDesc, columnName) => {
if (!columns[columnName]) {
changes.push(() => this.QueryInterface.addColumn(this.getTableName(options), columnName, attributes[columnName]));
}
});
_.each(columns, (columnDesc, columnName) => {
if (!attributes[columnName]) {
const currentAttributes = attributes[columnName];
if (!currentAttributes) {
changes.push(() => this.QueryInterface.removeColumn(this.getTableName(options), columnName, options));
} else if (!attributes[columnName].primaryKey) {
} else if (!currentAttributes.primaryKey) {
// Check foreign keys. If it's a foreign key, it should remove constraint first.
const references = currentAttributes.references;
if (currentAttributes.references) {
const database = this.sequelize.config.database;
const schema = this.sequelize.config.schema;
// Find existed foreign keys
_.each(foreignKeyReferences, foreignKeyReference => {
const constraintName = foreignKeyReference.constraintName;
if (!!constraintName
&& foreignKeyReference.tableCatalog === database
&& (schema ? foreignKeyReference.tableSchema === schema : true)
&& foreignKeyReference.referencedTableName === references.model
&& foreignKeyReference.referencedColumnName === references.key
&& (schema ? foreignKeyReference.referencedTableSchema === schema : true)
&& !removedConstraints[constraintName]) {
// Remove constraint on foreign keys.
changes.push(() => this.QueryInterface.removeConstraint(this.getTableName(options), constraintName, options));
removedConstraints[constraintName] = true;
}
});
}
changes.push(() => this.QueryInterface.changeColumn(this.getTableName(options), columnName, attributes[columnName]));
}
});
Expand Down

0 comments on commit bb2d0bd

Please sign in to comment.