Pg & Mysql schema reading & indexing fks

This commit is contained in:
Alexandre Bodin 2021-09-16 11:37:44 +02:00
parent c173fa416e
commit 72b5a19a7c
13 changed files with 365 additions and 121 deletions

View File

@ -28,6 +28,9 @@ class Dialect {
return false;
}
async startSchemaUpdate() {}
async endSchemaUpdate() {}
// TODO: pass query info to display some more metadata
transformErrors(error) {
if (error instanceof Error) {

View File

@ -1,8 +1,15 @@
'use strict';
const { Dialect } = require('../dialect');
const MysqlSchemaInspector = require('./schema-inspector');
class MysqlDialect extends Dialect {
constructor(db) {
super(db);
this.schemaInspector = new MysqlSchemaInspector(db);
}
configure() {
this.db.config.connection.connection.supportBigNumbers = true;
this.db.config.connection.connection.bigNumberStrings = true;
@ -20,6 +27,14 @@ class MysqlDialect extends Dialect {
};
}
async startSchemaUpdate() {
await this.db.connection.raw(`set foreign_key_checks = 0;`);
}
async endSchemaUpdate() {
await this.db.connection.raw(`set foreign_key_checks = 1;`);
}
supportsUnsigned() {
return true;
}

View File

@ -0,0 +1,208 @@
'use strict';
const SQL_QUERIES = {
TABLE_LIST: /* sql */ `
SELECT
t.table_name as table_name
FROM information_schema.tables t
WHERE table_type = 'BASE TABLE'
AND table_schema = schema();
`,
LIST_COLUMNS: /* sql */ `
SELECT
c.data_type as data_type,
c.column_name as column_name,
c.character_maximum_length as character_maximum_length,
c.column_default as column_default,
c.is_nullable as is_nullable,
c.column_type as column_type,
c.column_key as column_key
FROM information_schema.columns c
WHERE table_schema = database()
AND table_name = ?;
`,
INDEX_LIST: /* sql */ `
show index from ??;
`,
FOREIGN_KEY_LIST: /* sql */ `
SELECT
tc.constraint_name as constraint_name,
kcu.column_name as column_name,
kcu.referenced_table_name as referenced_table_name,
kcu.referenced_column_name as referenced_column_name,
rc.update_rule as on_update,
rc.delete_rule as on_delete
FROM information_schema.table_constraints tc
INNER JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name
INNER JOIN information_schema.referential_constraints AS rc ON kcu.constraint_name = rc.constraint_name
WHERE constraint_type = 'FOREIGN KEY'
AND tc.table_schema = database()
AND tc.table_name = ?;
`,
};
const toStrapiType = column => {
const rootType = column.data_type.toLowerCase().match(/[^(), ]+/)[0];
switch (rootType) {
case 'int': {
if (column.column_key === 'PRI') {
return { type: 'increments', args: [{ primary: true }], unsigned: false };
}
return { type: 'integer' };
}
case 'decimal': {
return { type: 'decimal', args: [10, 2] };
}
case 'float': {
return { type: 'float', args: [10, 2] };
}
case 'bigint': {
return { type: 'bigInteger' };
}
case 'enum': {
return { type: 'enum' };
}
case 'tinyint': {
return { type: 'boolean' };
}
case 'longtext': {
return { type: 'text', args: ['longtext'] };
}
case 'varchar': {
if (Number(column.character_maximum_length) === 255) {
return { type: 'string', args: [] };
}
return { type: 'string', args: [column.character_maximum_length] };
}
case 'datetime': {
return { type: 'datetime', args: [{ useTz: false, precision: 6 }] };
}
case 'date': {
return { type: 'date' };
}
case 'time': {
return { type: 'time', args: [{ precision: 3 }] };
}
case 'timestamp': {
return { type: 'timestamp', args: [{ useTz: false, precision: 6 }] };
}
case 'json': {
return { type: 'jsonb' };
}
default: {
return { type: 'specificType', args: [column.data_type] };
}
}
};
class MysqlSchemaInspector {
constructor(db) {
this.db = db;
}
async getSchema() {
const schema = { tables: [] };
const tables = await this.getTables();
schema.tables = await Promise.all(
tables.map(async tableName => {
const columns = await this.getColumns(tableName);
const indexes = await this.getIndexes(tableName);
const foreignKeys = await this.getForeignKeys(tableName);
return {
name: tableName,
columns,
indexes,
foreignKeys,
};
})
);
return schema;
}
getDatabaseSchema() {
return this.db.connection.client.connectionSettings.schema || 'public';
}
async getTables() {
const [rows] = await this.db.connection.raw(SQL_QUERIES.TABLE_LIST);
return rows.map(row => row.table_name);
}
async getColumns(tableName) {
const [rows] = await this.db.connection.raw(SQL_QUERIES.LIST_COLUMNS, [tableName]);
return rows.map(row => {
const { type, args = [], ...rest } = toStrapiType(row);
return {
type,
args,
defaultTo: row.column_default,
name: row.column_name,
notNullable: row.is_nullable === 'NO',
unsigned: row.column_type.endsWith(' unsigned'),
...rest,
};
});
}
async getIndexes(tableName) {
const [rows] = await this.db.connection.raw(SQL_QUERIES.INDEX_LIST, [tableName]);
const ret = {};
for (const index of rows) {
if (index.Column_name === 'id') {
continue;
}
if (!ret[index.Key_name]) {
ret[index.Key_name] = {
columns: [index.Column_name],
name: index.Key_name,
type: !index.Non_unique ? 'unique' : null,
};
} else {
ret[index.Key_name].columns.push(index.Column_name);
}
}
return Object.values(ret);
}
async getForeignKeys(tableName) {
const [rows] = await this.db.connection.raw(SQL_QUERIES.FOREIGN_KEY_LIST, [tableName]);
const ret = {};
for (const fk of rows) {
if (!ret[fk.constraint_name]) {
ret[fk.constraint_name] = {
name: fk.constraint_name,
columns: [fk.column_name],
referencedColumns: [fk.referenced_column_name],
referencedTable: fk.referenced_table_name,
onUpdate: fk.on_update.toUpperCase(),
onDelete: fk.on_delete.toUpperCase(),
};
} else {
ret[fk.constraint_name].columns.push(fk.column_name);
ret[fk.constraint_name].referencedColumns.push(fk.referenced_column_name);
}
}
return Object.values(ret);
}
}
module.exports = MysqlSchemaInspector;

View File

@ -23,6 +23,17 @@ class PostgresDialect extends Dialect {
return true;
}
getSqlType(type) {
switch (type) {
case 'timestamp': {
return 'datetime';
}
default: {
return type;
}
}
}
transformErrors(error) {
switch (error.code) {
case '23502': {

View File

@ -7,7 +7,7 @@ const SQL_QUERIES = {
WHERE table_schema = ? AND table_type = 'BASE TABLE';
`,
LIST_COLUMNS: /* sql */ `
SELECT *
SELECT data_type, column_name, character_maximum_length, column_default, is_nullable
FROM information_schema.columns
WHERE table_schema = ?
AND table_name = ?;
@ -37,13 +37,12 @@ const SQL_QUERIES = {
`,
FOREIGN_KEY_LIST: /* sql */ `
SELECT
tco."constraint_name" as contraint_name,
tco."constraint_name" as constraint_name,
kcu."column_name" as column_name,
rel_kcu."table_name" as foreign_table,
rel_kcu."column_name" as fk_column_name,
rco.update_rule as on_update,
rco.delete_rule as on_delete,
*
rco.delete_rule as on_delete
FROM information_schema.table_constraints tco
JOIN information_schema.key_column_usage kcu
ON tco.constraint_schema = kcu.constraint_schema
@ -64,26 +63,6 @@ const SQL_QUERIES = {
};
const toStrapiType = column => {
// 'int2': 'smallint',
// 'smallserial': 'smallint',
// 'int': 'integer',
// 'int4': 'integer',
// 'serial': 'integer',
// 'serial4': 'integer',
// 'int8': 'bigint',
// 'bigserial': 'bigint',
// 'serial8': 'bigint',
// 'numeric': 'decimal',
// 'bool': 'boolean',
// 'real': 'float',
// 'float4': 'float',
// 'float8': 'double',
// 'timestamp': 'datetime',
// 'timestamptz': 'datetime',
// 'bytea': 'blob',
// 'jsonb': 'json',
// 'character varying': 'varchar',
const rootType = column.data_type.toLowerCase().match(/[^(), ]+/)[0];
switch (rootType) {
@ -113,8 +92,11 @@ const toStrapiType = column => {
case 'time': {
return { type: 'time', args: [{ precision: 3 }] };
}
case 'double':
case 'numeric': {
return { type: 'decimal', args: [10, 2] };
}
case 'real':
case 'double': {
return { type: 'float', args: [10, 2] };
}
case 'bigint': {
@ -124,8 +106,6 @@ const toStrapiType = column => {
return { type: 'jsonb' };
}
default: {
console.log(rootType);
return { type: 'specificType', args: [column.data_type] };
}
}
@ -138,20 +118,23 @@ class PostgresqlSchemaInspector {
async getSchema() {
const schema = { tables: [] };
const tables = await this.getTables();
for (const tableName of tables) {
const columns = await this.getColumns(tableName);
const indexes = await this.getIndexes(tableName);
const foreignKeys = await this.getForeignKeys(tableName);
schema.tables = await Promise.all(
tables.map(async tableName => {
const columns = await this.getColumns(tableName);
const indexes = await this.getIndexes(tableName);
const foreignKeys = await this.getForeignKeys(tableName);
schema.tables.push({
name: tableName,
columns,
indexes,
foreignKeys,
});
}
return {
name: tableName,
columns,
indexes,
foreignKeys,
};
})
);
return schema;
}
@ -209,7 +192,6 @@ class PostgresqlSchemaInspector {
ret[index.indexrelid] = {
columns: [index.column_name],
name: index.index_name,
// TODO: find other index types
type: index.is_primary ? 'primary' : index.is_unique ? 'unique' : null,
};
} else {
@ -235,8 +217,8 @@ class PostgresqlSchemaInspector {
columns: [fk.column_name],
referencedColumns: [fk.fk_column_name],
referencedTable: fk.foreign_table,
onUpdate: fk.on_update.toLowerCase(),
onDelete: fk.on_delete.toLowerCase(),
onUpdate: fk.on_update.toUpperCase(),
onDelete: fk.on_delete.toUpperCase(),
};
} else {
ret[fk.constraint_name].columns.push(fk.column_name);

View File

@ -51,6 +51,14 @@ class SqliteDialect extends Dialect {
}
}
async startSchemaUpdate() {
await this.db.connection.raw(`pragma foreign_keys = off`);
}
async endSchemaUpdate() {
await this.db.connection.raw(`pragma foreign_keys = on`);
}
transformErrors(error) {
switch (error.errno) {
case 19: {

View File

@ -149,8 +149,8 @@ class SqliteSchemaInspector {
columns: [fk.from],
referencedColumns: [fk.to],
referencedTable: fk.table,
onUpdate: fk.on_update.toLowerCase(),
onDelete: fk.on_delete.toLowerCase(),
onUpdate: fk.on_update.toUpperCase(),
onDelete: fk.on_delete.toUpperCase(),
};
} else {
ret[fk.id].columns.push(fk.from);

View File

@ -216,6 +216,10 @@ const createCompoLinkModelMeta = baseModelMeta => {
columns: ['component_type'],
type: null,
},
{
name: `${baseModelMeta.tableName}_entity_fk`,
columns: ['entity_id'],
},
],
foreignKeys: [
{

View File

@ -235,6 +235,12 @@ const createMorphToMany = (attributeName, attribute, meta, metadata) => {
},
},
},
indexes: [
{
name: `${joinTableName}_fk`,
columns: [joinColumnName],
},
],
foreignKeys: [
{
name: `${joinTableName}_fk`,
@ -415,6 +421,16 @@ const createJoinTable = (metadata, { attributeName, attribute, meta }) => {
},
// TODO: add extra pivot attributes -> user should use an intermediate entity
},
indexes: [
{
name: `${joinTableName}_fk`,
columns: [joinColumnName],
},
{
name: `${joinTableName}_inv_fk`,
columns: [inverseJoinColumnName],
},
],
foreignKeys: [
{
name: `${joinTableName}_fk`,

View File

@ -73,6 +73,7 @@ module.exports = db => {
*/
// TODO: implement force option to disable removal in DB
async updateSchema(schemaDiff) {
await db.dialect.startSchemaUpdate();
await db.connection.transaction(async trx => {
await this.createTables(schemaDiff.tables.added, trx);
@ -99,6 +100,8 @@ module.exports = db => {
await helpers.alterTable(schemaBuilder, table);
}
});
await db.dialect.endSchemaUpdate();
},
};
};

View File

@ -1,6 +1,5 @@
'use strict';
const util = require('util');
const createSchemaBuilder = require('./builder');
const createSchemaStorage = require('./schema-storage');
const createSchemaDiff = require('./schema-diff');
@ -83,32 +82,6 @@ const createSchemaProvider = db => {
// diff schema
const { status, diff } = this.schemaDiff.diff(schemaInspect, currentSchema);
console.log('added :', diff.tables.added.length);
console.log('removed :', diff.tables.removed.length);
console.log('unchanged :', diff.tables.unchanged.length);
console.log('updated :', diff.tables.updated.length);
diff.tables.updated.forEach(table => {
console.log(table.name);
console.log('\tCOLUMNS:');
table.columns.updated.forEach(column => {
console.log(`\t\t${column.name}`);
});
console.log('\tINDEXES:');
table.indexes.updated.forEach(index => {
console.log(`\t\t${index.name}`);
});
console.log('\tFKS:');
table.foreignKeys.updated.forEach(fk => {
console.log(`\t\t${fk.name}`);
});
});
console.log(util.inspect(diff, null, null, true));
if (status === 'UNCHANGED') {
return;
}

View File

@ -43,50 +43,72 @@ const helpers = {
module.exports = db => {
const hasChangedStatus = diff => diff.status === statuses.CHANGED;
const diffProperties = (srcObject, destObject) => {
const addedProperties = [];
const updatedProperties = [];
const unchangedProperties = [];
const removedProperties = [];
/**
* Compares two indexes info
* @param {Object} oldIndex - index info read from DB
* @param {Object} index - newly generate index info
*/
const diffIndexes = (oldIndex, index) => {
const changes = [];
for (const key in destObject) {
const value = destObject[key];
if (_.has(key, srcObject)) {
const srcValue = srcObject[key];
if (_.isEqual(srcValue, value)) {
unchangedProperties.push({ key, value });
} else {
updatedProperties.push({ key, oldValue: srcValue, value });
}
} else {
addedProperties.push({ key, value });
}
if (_.difference(oldIndex.columns, index.columns).length > 0) {
changes.push('columns');
}
for (const key in srcObject) {
const value = srcObject[key];
if (!_.has(key, destObject)) {
removedProperties.push({ key, oldValue: value });
}
if (_.toLower(oldIndex.type) !== _.toLower(index.type)) {
changes.push('type');
}
const hasChanged = [addedProperties, updatedProperties, removedProperties].some(
arr => arr.length > 0
);
return {
status: hasChanged ? statuses.CHANGED : statuses.UNCHANGED,
status: changes.length > 0 ? statuses.CHANGED : statuses.UNCHANGED,
diff: {
name: destObject.name,
object: destObject,
// NOTE: maybe put into properties: {}
added: addedProperties,
updated: updatedProperties,
unchanged: unchangedProperties,
removed: removedProperties,
name: index.name,
object: index,
},
};
};
/**
* Compares two foreign keys info
* @param {Object} oldForeignKey - foreignKey info read from DB
* @param {Object} foreignKey - newly generate foreignKey info
*/
const diffForeignKeys = (oldForeignKey, foreignKey) => {
const changes = [];
if (_.difference(oldForeignKey.columns, foreignKey.columns).length > 0) {
changes.push('columns');
}
if (_.difference(oldForeignKey.referencedColumns, foreignKey.referencedColumns).length > 0) {
changes.push('referencedColumns');
}
if (oldForeignKey.referencedTable !== foreignKey.referencedTable) {
changes.push('referencedTable');
}
if (_.isNil(oldForeignKey.onDelete) || _.toUpper(oldForeignKey.onDelete) === 'NO ACTION') {
if (!_.isNil(foreignKey.onDelete) && _.toUpper(oldForeignKey.onDelete) !== 'NO ACTION') {
changes.push('onDelete');
}
} else if (_.toUpper(oldForeignKey.onDelete) !== _.toUpper(foreignKey.onDelete)) {
changes.push('onDelete');
}
if (_.isNil(oldForeignKey.onUpdate) || _.toUpper(oldForeignKey.onUpdate) === 'NO ACTION') {
if (!_.isNil(foreignKey.onUpdate) && _.toUpper(oldForeignKey.onUpdate) !== 'NO ACTION') {
changes.push('onUpdate');
}
} else if (_.toUpper(oldForeignKey.onUpdate) !== _.toUpper(foreignKey.onUpdate)) {
changes.push('onUpdate');
}
return {
status: changes.length > 0 ? statuses.CHANGED : statuses.UNCHANGED,
diff: {
name: foreignKey.name,
object: foreignKey,
},
};
};
@ -99,11 +121,10 @@ module.exports = db => {
return _.isNil(defaultTo) || _.toLower(defaultTo) === 'null';
}
if (!_.isNil(oldDefaultTo) && !_.isNil(defaultTo)) {
return _.toLower(oldDefaultTo) === _.toLower(`'${column.defaultTo}'`);
}
return oldDefaultTo === defaultTo;
return (
_.toLower(oldDefaultTo) === _.toLower(column.defaultTo) ||
_.toLower(oldDefaultTo) === _.toLower(`'${column.defaultTo}'`)
);
};
/**
@ -122,7 +143,7 @@ module.exports = db => {
changes.push('type');
}
if (!_.isEqual(oldColumn.args, column.args) && !['increments', 'enum'].includes(type)) {
if (!_.isEqual(oldColumn.args, column.args) && !['increments', 'enum'].includes(column.type)) {
changes.push('args');
}
@ -139,10 +160,6 @@ module.exports = db => {
changes.push('unsigned');
}
if (changes.length > 0) {
console.log(`Changes in ${column.name}, ${changes}`);
}
return {
status: changes.length > 0 ? statuses.CHANGED : statuses.UNCHANGED,
diff: {
@ -202,7 +219,7 @@ module.exports = db => {
for (const destIndex of destTable.indexes) {
if (helpers.hasIndex(srcTable, destIndex.name)) {
const srcIndex = helpers.findIndex(srcTable, destIndex.name);
const { status, diff } = diffProperties(srcIndex, destIndex);
const { status, diff } = diffIndexes(srcIndex, destIndex);
if (status === statuses.CHANGED) {
updatedIndexes.push(diff);
@ -254,7 +271,7 @@ module.exports = db => {
for (const destForeignKey of destTable.foreignKeys) {
if (helpers.hasForeignKey(srcTable, destForeignKey.name)) {
const srcForeignKey = helpers.findForeignKey(srcTable, destForeignKey.name);
const { status, diff } = diffProperties(srcForeignKey, destForeignKey);
const { status, diff } = diffForeignKeys(srcForeignKey, destForeignKey);
if (status === statuses.CHANGED) {
updatedForeignKeys.push(diff);
@ -313,7 +330,6 @@ module.exports = db => {
for (const destTable of destSchema.tables) {
if (helpers.hasTable(srcSchema, destTable.name)) {
// either changed or unchanged
const srcTable = helpers.findTable(srcSchema, destTable.name);
const { status, diff } = diffTables(srcTable, destTable);
@ -329,7 +345,7 @@ module.exports = db => {
}
for (const srcTable of srcSchema.tables) {
if (!helpers.hasTable(destSchema, srcTable.name)) {
if (!helpers.hasTable(destSchema, srcTable.name) && srcTable.name !== 'strapi_migrations') {
removedTables.push(srcTable);
}
}

View File

@ -70,6 +70,11 @@ const createTable = meta => {
// NOTE: could allow configuration
onDelete: 'SET NULL',
});
table.indexes.push({
name: `${table.name}_${columnName}_fk`,
columns: [columnName],
});
}
} else if (shouldCreateColumn(attribute)) {
const column = createColumn(key, meta.attributes[key]);