mysql - analyse primary and foreign keys

This commit is contained in:
Jan Prochazka 2020-05-16 08:45:18 +02:00
parent 70ab03ad73
commit 83e3f8b1d8
7 changed files with 81 additions and 39 deletions

View File

@ -1,4 +1,5 @@
const _ = require('lodash');
const fp = require('lodash/fp');
class DatabaseAnalyser {
/**
@ -89,4 +90,34 @@ DatabaseAnalyser.createEmptyStructure = () => ({
triggers: [],
});
DatabaseAnalyser.byTableFilter = (table) => (x) => x.pureName == table.pureName && x.schemaName == x.schemaName;
DatabaseAnalyser.extractPrimaryKeys = (table, pkColumns) => {
const filtered = pkColumns.filter(DatabaseAnalyser.byTableFilter(table));
if (filtered.length == 0) return undefined;
return {
..._.pick(filtered[0], ['constraintName', 'schemaName', 'pureName']),
constraintType: 'primaryKey',
columns: filtered.map(fp.pick('columnName')),
};
};
DatabaseAnalyser.extractForeignKeys = (table, fkColumns) => {
const grouped = _.groupBy(fkColumns.filter(DatabaseAnalyser.byTableFilter(table)), 'constraintName');
return _.keys(grouped).map((constraintName) => ({
constraintName,
constraintType: 'foreignKey',
..._.pick(grouped[constraintName][0], [
'constraintName',
'schemaName',
'pureName',
'refSchemaName',
'refTableName',
'updateAction',
'deleteAction',
]),
columns: grouped[constraintName].map(fp.pick(['columnName', 'refColumnName'])),
}));
};
module.exports = DatabaseAnalyser;

View File

@ -2,37 +2,7 @@ const fp = require('lodash/fp');
const _ = require('lodash');
const sql = require('./sql');
const DatabaseAnalayser = require('../default/DatabaseAnalyser');
const byTableFilter = (table) => (x) => x.pureName == table.pureName && x.schemaName == x.schemaName;
function extractPrimaryKeys(table, pkColumns) {
const filtered = pkColumns.filter(byTableFilter(table));
if (filtered.length == 0) return undefined;
return {
..._.pick(filtered[0], ['constraintName', 'schemaName', 'pureName']),
constraintType: 'primaryKey',
columns: filtered.map(fp.pick('columnName')),
};
}
function extractForeignKeys(table, fkColumns) {
const grouped = _.groupBy(fkColumns.filter(byTableFilter(table)), 'constraintName');
return _.keys(grouped).map((constraintName) => ({
constraintName,
constraintType: 'foreignKey',
..._.pick(grouped[constraintName][0], [
'constraintName',
'schemaName',
'pureName',
'refSchemaName',
'refTableName',
'updateAction',
'deleteAction',
]),
columns: grouped[constraintName].map(fp.pick(['columnName', 'refColumnName'])),
}));
}
const DatabaseAnalyser = require('../default/DatabaseAnalyser');
function objectTypeToField(type) {
switch (type.trim()) {
@ -186,7 +156,7 @@ function detectType(col) {
};
}
class MsSqlAnalyser extends DatabaseAnalayser {
class MsSqlAnalyser extends DatabaseAnalyser {
constructor(pool, driver) {
super(pool, driver);
}
@ -239,8 +209,8 @@ class MsSqlAnalyser extends DatabaseAnalayser {
autoIncrement: !!isIdentity,
commonType: detectType(col),
})),
primaryKey: extractPrimaryKeys(row, pkColumnsRows.rows),
foreignKeys: extractForeignKeys(row, fkColumnsRows.rows),
primaryKey: DatabaseAnalyser.extractPrimaryKeys(row, pkColumnsRows.rows),
foreignKeys: DatabaseAnalyser.extractForeignKeys(row, fkColumnsRows.rows),
}));
const views = viewsRows.rows.map((row) => ({

View File

@ -18,8 +18,8 @@ class MySqlAnalyser extends DatabaseAnalayser {
async _runAnalysis() {
const tables = await this.driver.query(this.pool, this.createQuery('tables'));
const columns = await this.driver.query(this.pool, this.createQuery('columns'));
// const pkColumns = await this.driver.query(this.pool, this.createQuery('primary_keys.sql'));
// const fkColumns = await this.driver.query(this.pool, this.createQuery('foreign_keys.sql'));
const pkColumns = await this.driver.query(this.pool, this.createQuery('primary_keys'));
const fkColumns = await this.driver.query(this.pool, this.createQuery('foreign_keys'));
return this.mergeAnalyseResult({
tables: tables.rows.map((table) => ({
@ -31,9 +31,8 @@ class MySqlAnalyser extends DatabaseAnalayser {
notNull: !isNullable,
autoIncrement: extra && extra.toLowerCase().includes('auto_increment'),
})),
foreignKeys: [],
// primaryKey: extractPrimaryKeys(table, pkColumns.rows),
// foreignKeys: extractForeignKeys(table, fkColumns.rows),
primaryKey: DatabaseAnalayser.extractPrimaryKeys(table, pkColumns.rows),
foreignKeys: DatabaseAnalayser.extractForeignKeys(table, fkColumns.rows),
})),
});
}

View File

@ -0,0 +1,17 @@
module.exports = `
select
REFERENTIAL_CONSTRAINTS.CONSTRAINT_NAME as constraintName,
REFERENTIAL_CONSTRAINTS.TABLE_NAME as pureName,
REFERENTIAL_CONSTRAINTS.UPDATE_RULE as updateAction,
REFERENTIAL_CONSTRAINTS.DELETE_RULE as deleteAction,
REFERENTIAL_CONSTRAINTS.REFERENCED_TABLE_NAME as refTableName,
KEY_COLUMN_USAGE.COLUMN_NAME as columnName,
KEY_COLUMN_USAGE.REFERENCED_COLUMN_NAME as refColumnName
from INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS
inner join INFORMATION_SCHEMA.KEY_COLUMN_USAGE
on REFERENTIAL_CONSTRAINTS.TABLE_NAME = KEY_COLUMN_USAGE.TABLE_NAME
and REFERENTIAL_CONSTRAINTS.CONSTRAINT_NAME = KEY_COLUMN_USAGE.CONSTRAINT_NAME
and REFERENTIAL_CONSTRAINTS.CONSTRAINT_SCHEMA = KEY_COLUMN_USAGE.CONSTRAINT_SCHEMA
where REFERENTIAL_CONSTRAINTS.CONSTRAINT_SCHEMA = '#DATABASE#' and REFERENTIAL_CONSTRAINTS.TABLE_NAME =[OBJECT_NAME_CONDITION]
order by KEY_COLUMN_USAGE.ORDINAL_POSITION
`;

View File

@ -1,7 +1,13 @@
const columns = require('./columns');
const tables = require('./tables');
const primary_keys = require('./primary_keys');
const foreign_keys = require('./foreign_keys');
const table_modifications = require('./table_modifications');
module.exports = {
columns,
tables,
primary_keys,
foreign_keys,
table_modifications,
};

View File

@ -0,0 +1,12 @@
module.exports = `select
TABLE_CONSTRAINTS.CONSTRAINT_NAME as constraintName,
TABLE_CONSTRAINTS.TABLE_NAME as pureName,
KEY_COLUMN_USAGE.COLUMN_NAME as columnName
from INFORMATION_SCHEMA.TABLE_CONSTRAINTS
inner join INFORMATION_SCHEMA.KEY_COLUMN_USAGE
on TABLE_CONSTRAINTS.TABLE_NAME = KEY_COLUMN_USAGE.TABLE_NAME
and TABLE_CONSTRAINTS.CONSTRAINT_NAME = KEY_COLUMN_USAGE.CONSTRAINT_NAME
and TABLE_CONSTRAINTS.CONSTRAINT_SCHEMA = KEY_COLUMN_USAGE.CONSTRAINT_SCHEMA
where TABLE_CONSTRAINTS.CONSTRAINT_SCHEMA = '#DATABASE#' and TABLE_CONSTRAINTS.TABLE_NAME =[OBJECT_NAME_CONDITION] AND TABLE_CONSTRAINTS.CONSTRAINT_TYPE = 'PRIMARY KEY'
order by KEY_COLUMN_USAGE.ORDINAL_POSITION
`;

View File

@ -0,0 +1,7 @@
module.exports = `
select
TABLE_NAME,
case when ENGINE='InnoDB' then CREATE_TIME else coalesce(UPDATE_TIME, CREATE_TIME) end as ALTER_TIME
from information_schema.tables
where TABLE_SCHEMA = '#DATABASE#'
`;