From a88e38dcf78125d4a84a408150a62c3cc30080df Mon Sep 17 00:00:00 2001 From: Jan Prochazka Date: Mon, 28 Sep 2020 11:33:25 +0200 Subject: [PATCH] postgre incremental analysis, fixed mysql incremental analysis --- packages/engines/default/DatabaseAnalyser.js | 8 +- packages/engines/mssql/MsSqlAnalyser.js | 17 ++- packages/engines/mysql/MySqlAnalyser.js | 38 ++--- packages/engines/postgres/PostgreAnalyser.js | 131 +++++++++++++++--- packages/engines/postgres/index.js | 10 ++ packages/engines/postgres/sql/columns.js | 2 +- packages/engines/postgres/sql/foreignKeys.js | 2 +- packages/engines/postgres/sql/index.js | 4 + packages/engines/postgres/sql/primaryKeys.js | 2 +- .../postgres/sql/routineModifications.js | 10 ++ packages/engines/postgres/sql/routines.js | 7 +- .../postgres/sql/tableModifications.js | 4 +- .../engines/postgres/sql/viewModifications.js | 8 ++ packages/engines/postgres/sql/views.js | 4 +- 14 files changed, 194 insertions(+), 53 deletions(-) create mode 100644 packages/engines/postgres/sql/routineModifications.js create mode 100644 packages/engines/postgres/sql/viewModifications.js diff --git a/packages/engines/default/DatabaseAnalyser.js b/packages/engines/default/DatabaseAnalyser.js index 50457e8d..dea9bb42 100644 --- a/packages/engines/default/DatabaseAnalyser.js +++ b/packages/engines/default/DatabaseAnalyser.js @@ -46,7 +46,7 @@ class DatabaseAnalyser { return this._runAnalysis(); } - mergeAnalyseResult(newlyAnalysed) { + mergeAnalyseResult(newlyAnalysed, extractObjectId) { if (this.structure == null) { return { ...DatabaseAnalyser.createEmptyStructure(), @@ -58,12 +58,12 @@ class DatabaseAnalyser { for (const field of ['tables', 'views', 'functions', 'procedures', 'triggers']) { const removedIds = this.modifications .filter((x) => x.action == 'remove' && x.objectTypeField == field) - .map((x) => x.objectId); + .map((x) => extractObjectId(x)); const newArray = newlyAnalysed[field] || []; - const addedChangedIds = newArray.map((x) => x.objectId); + const addedChangedIds = newArray.map((x) => extractObjectId(x)); const removeAllIds = [...removedIds, ...addedChangedIds]; res[field] = _.sortBy( - [...this.structure[field].filter((x) => !removeAllIds.includes(x.objectId)), ...newArray], + [...this.structure[field].filter((x) => !removeAllIds.includes(extractObjectId(x))), ...newArray], (x) => x.pureName ); } diff --git a/packages/engines/mssql/MsSqlAnalyser.js b/packages/engines/mssql/MsSqlAnalyser.js index 6464da00..9363dc08 100644 --- a/packages/engines/mssql/MsSqlAnalyser.js +++ b/packages/engines/mssql/MsSqlAnalyser.js @@ -137,13 +137,16 @@ class MsSqlAnalyser extends DatabaseAnalyser { createSql: getCreateSql(row), })); - return this.mergeAnalyseResult({ - tables, - views, - procedures, - functions, - schemas, - }); + return this.mergeAnalyseResult( + { + tables, + views, + procedures, + functions, + schemas, + }, + (x) => x.objectId + ); } getDeletedObjectsForField(idArray, objectTypeField) { diff --git a/packages/engines/mysql/MySqlAnalyser.js b/packages/engines/mysql/MySqlAnalyser.js index 3b7dc4b4..fd5f145f 100644 --- a/packages/engines/mysql/MySqlAnalyser.js +++ b/packages/engines/mysql/MySqlAnalyser.js @@ -53,7 +53,8 @@ class MySqlAnalyser extends DatabaseAnalayser { } else { const filterNames = this.modifications .filter((x) => typeFields.includes(x.objectTypeField) && (x.action == 'add' || x.action == 'change')) - .map((x) => x.objectId); + .map((x) => x.newName && x.newName.pureName) + .filter(Boolean); if (filterNames.length == 0) { res = res.replace('=[OBJECT_NAME_CONDITION]', ' IS NULL'); } else { @@ -97,22 +98,25 @@ class MySqlAnalyser extends DatabaseAnalayser { const viewTexts = await this.getViewTexts(views.rows.map((x) => x.pureName)); - return this.mergeAnalyseResult({ - tables: tables.rows.map((table) => ({ - ...table, - columns: columns.rows.filter((col) => col.pureName == table.pureName).map(getColumnInfo), - primaryKey: DatabaseAnalayser.extractPrimaryKeys(table, pkColumns.rows), - foreignKeys: DatabaseAnalayser.extractForeignKeys(table, fkColumns.rows), - })), - views: views.rows.map((view) => ({ - ...view, - columns: columns.rows.filter((col) => col.pureName == view.pureName).map(getColumnInfo), - createSql: viewTexts[view.pureName], - requiresFormat: true, - })), - procedures: programmables.rows.filter((x) => x.objectType == 'PROCEDURE').map(fp.omit(['objectType'])), - functions: programmables.rows.filter((x) => x.objectType == 'FUNCTION').map(fp.omit(['objectType'])), - }); + return this.mergeAnalyseResult( + { + tables: tables.rows.map((table) => ({ + ...table, + columns: columns.rows.filter((col) => col.pureName == table.pureName).map(getColumnInfo), + primaryKey: DatabaseAnalayser.extractPrimaryKeys(table, pkColumns.rows), + foreignKeys: DatabaseAnalayser.extractForeignKeys(table, fkColumns.rows), + })), + views: views.rows.map((view) => ({ + ...view, + columns: columns.rows.filter((col) => col.pureName == view.pureName).map(getColumnInfo), + createSql: viewTexts[view.pureName], + requiresFormat: true, + })), + procedures: programmables.rows.filter((x) => x.objectType == 'PROCEDURE').map(fp.omit(['objectType'])), + functions: programmables.rows.filter((x) => x.objectType == 'FUNCTION').map(fp.omit(['objectType'])), + }, + (x) => x.pureName + ); } getDeletedObjectsForField(nameArray, objectTypeField) { diff --git a/packages/engines/postgres/PostgreAnalyser.js b/packages/engines/postgres/PostgreAnalyser.js index c91d2154..9a5fc798 100644 --- a/packages/engines/postgres/PostgreAnalyser.js +++ b/packages/engines/postgres/PostgreAnalyser.js @@ -42,8 +42,31 @@ class PostgreAnalyser extends DatabaseAnalayser { createQuery(resFileName, typeFields) { let res = sql[resFileName]; - res = res.replace('=[OBJECT_ID_CONDITION]', ' is not null'); + + if (this.singleObjectFilter) { + const { typeField, schemaName, pureName } = this.singleObjectFilter; + if (!typeFields || !typeFields.includes(typeField)) return null; + res = res.replace(/=OBJECT_ID_CONDITION/g, ` = '${typeField}:${schemaName}.${pureName}'`); + return res; + } + if (!this.modifications || !typeFields || this.modifications.length == 0) { + res = res.replace(/=OBJECT_ID_CONDITION/g, ' is not null'); + } else { + const filterNames = this.modifications + .filter((x) => typeFields.includes(x.objectTypeField) && (x.action == 'add' || x.action == 'change')) + .filter((x) => x.newName) + .map((x) => `${x.objectTypeField}:${x.newName.schemaName}.${x.newName.pureName}`); + if (filterNames.length == 0) { + res = res.replace(/=OBJECT_ID_CONDITION/g, ' IS NULL'); + } else { + res = res.replace(/=OBJECT_ID_CONDITION/g, ` in (${filterNames.map((x) => `'${x}'`).join(',')})`); + } + } return res; + + // let res = sql[resFileName]; + // res = res.replace('=[OBJECT_ID_CONDITION]', ' is not null'); + // return res; } async _runAnalysis() { const tables = await this.driver.query(this.pool, this.createQuery('tableModifications', ['tables'])); @@ -54,24 +77,96 @@ class PostgreAnalyser extends DatabaseAnalayser { const routines = await this.driver.query(this.pool, this.createQuery('routines', ['procedures', 'functions'])); // console.log('PG fkColumns', fkColumns.rows); - return this.mergeAnalyseResult({ - tables: tables.rows.map((table) => ({ - ...table, - columns: columns.rows - .filter((col) => col.pureName == table.pureName && col.schemaName == table.schemaName) - .map(getColumnInfo), - primaryKey: DatabaseAnalayser.extractPrimaryKeys(table, pkColumns.rows), - foreignKeys: DatabaseAnalayser.extractForeignKeys(table, fkColumns.rows), - })), - views: views.rows.map((view) => ({ - ...view, - columns: columns.rows - .filter((col) => col.pureName == view.pureName && col.schemaName == view.schemaName) - .map(getColumnInfo), - })), - procedures: routines.rows.filter((x) => x.objectType == 'PROCEDURE'), - functions: routines.rows.filter((x) => x.objectType == 'FUNCTION'), + return this.mergeAnalyseResult( + { + tables: tables.rows.map((table) => ({ + ...table, + columns: columns.rows + .filter((col) => col.pureName == table.pureName && col.schemaName == table.schemaName) + .map(getColumnInfo), + primaryKey: DatabaseAnalayser.extractPrimaryKeys(table, pkColumns.rows), + foreignKeys: DatabaseAnalayser.extractForeignKeys(table, fkColumns.rows), + })), + views: views.rows.map((view) => ({ + ...view, + columns: columns.rows + .filter((col) => col.pureName == view.pureName && col.schemaName == view.schemaName) + .map(getColumnInfo), + })), + procedures: routines.rows.filter((x) => x.objectType == 'PROCEDURE'), + functions: routines.rows.filter((x) => x.objectType == 'FUNCTION'), + }, + (x) => `${x.objectTypeField}:${x.schemaName}.${x.pureName}` + ); + } + + async getModifications() { + const tableModificationsQueryData = await this.driver.query(this.pool, this.createQuery('tableModifications')); + const viewModificationsQueryData = await this.driver.query(this.pool, this.createQuery('viewModifications')); + const routineModificationsQueryData = await this.driver.query(this.pool, this.createQuery('routineModifications')); + + const allModifications = _.compact([ + ...tableModificationsQueryData.rows.map((x) => ({ ...x, objectTypeField: 'tables' })), + ...viewModificationsQueryData.rows.map((x) => ({ ...x, objectTypeField: 'views' })), + ...routineModificationsQueryData.rows + .filter((x) => x.objectType == 'PROCEDURE') + .map((x) => ({ ...x, objectTypeField: 'procedures' })), + ...routineModificationsQueryData.rows + .filter((x) => x.objectType == 'FUNCTION') + .map((x) => ({ ...x, objectTypeField: 'functions' })), + ]); + + const modifications = allModifications.map((x) => { + const { objectTypeField, hashCode, pureName, schemaName } = x; + + if (!objectTypeField || !this.structure[objectTypeField]) return null; + const obj = this.structure[objectTypeField].find((x) => x.pureName == pureName && x.schemaName == schemaName); + + // object not modified + if (obj && obj.hashCode == hashCode) return null; + + // console.log('MODIFICATION OF ', objectTypeField, schemaName, pureName); + + /** @type {import('@dbgate/types').DatabaseModification} */ + const action = obj + ? { + newName: { schemaName, pureName }, + oldName: _.pick(obj, ['schemaName', 'pureName']), + action: 'change', + objectTypeField, + } + : { + newName: { schemaName, pureName }, + action: 'add', + objectTypeField, + }; + return action; }); + + return [ + ..._.compact(modifications), + ...this.getDeletedObjects([...allModifications.map((x) => `${x.schemaName}.${x.pureName}`)]), + ]; + } + + getDeletedObjectsForField(nameArray, objectTypeField) { + return this.structure[objectTypeField] + .filter((x) => !nameArray.includes(`${x.schemaName}.${x.pureName}`)) + .map((x) => ({ + oldName: _.pick(x, ['schemaName', 'pureName']), + action: 'remove', + objectTypeField, + })); + } + + getDeletedObjects(nameArray) { + return [ + ...this.getDeletedObjectsForField(nameArray, 'tables'), + ...this.getDeletedObjectsForField(nameArray, 'views'), + ...this.getDeletedObjectsForField(nameArray, 'procedures'), + ...this.getDeletedObjectsForField(nameArray, 'functions'), + ...this.getDeletedObjectsForField(nameArray, 'triggers'), + ]; } } diff --git a/packages/engines/postgres/index.js b/packages/engines/postgres/index.js index 131fa1f7..256ebb2d 100644 --- a/packages/engines/postgres/index.js +++ b/packages/engines/postgres/index.js @@ -97,6 +97,16 @@ const driver = { return stream; }, + async analyseSingleObject(pool, name, typeField = 'tables') { + const analyser = new PostgreAnalyser(pool, this); + analyser.singleObjectFilter = { ...name, typeField }; + const res = await analyser.fullAnalysis(); + return res.tables[0]; + }, + // @ts-ignore + analyseSingleTable(pool, name) { + return this.analyseSingleObject(pool, name, 'tables'); + }, async getVersion(client) { const { rows } = await this.query(client, 'SELECT version()'); const { version } = rows[0]; diff --git a/packages/engines/postgres/sql/columns.js b/packages/engines/postgres/sql/columns.js index 5c69a51f..841eda6b 100644 --- a/packages/engines/postgres/sql/columns.js +++ b/packages/engines/postgres/sql/columns.js @@ -14,6 +14,6 @@ where table_schema <> 'information_schema' and table_schema <> 'pg_catalog' and table_schema !~ '^pg_toast' - and 'table:' || table_schema || '.' || table_name =[OBJECT_ID_CONDITION] + and 'tables:' || table_schema || '.' || table_name =OBJECT_ID_CONDITION order by ordinal_position `; \ No newline at end of file diff --git a/packages/engines/postgres/sql/foreignKeys.js b/packages/engines/postgres/sql/foreignKeys.js index e869c71a..fadcf5e7 100644 --- a/packages/engines/postgres/sql/foreignKeys.js +++ b/packages/engines/postgres/sql/foreignKeys.js @@ -19,6 +19,6 @@ where base.table_schema <> 'information_schema' and base.table_schema <> 'pg_catalog' and base.table_schema !~ '^pg_toast' - and 'table:' || base.table_schema || '.' || base.table_name =[OBJECT_ID_CONDITION] + and 'tables:' || base.table_schema || '.' || base.table_name =OBJECT_ID_CONDITION order by basecol.ordinal_position `; diff --git a/packages/engines/postgres/sql/index.js b/packages/engines/postgres/sql/index.js index 1d8404b7..7cc2141e 100644 --- a/packages/engines/postgres/sql/index.js +++ b/packages/engines/postgres/sql/index.js @@ -1,15 +1,19 @@ const columns = require('./columns'); const tableModifications = require('./tableModifications'); +const viewModifications = require('./viewModifications'); const primaryKeys = require('./primaryKeys'); const foreignKeys = require('./foreignKeys'); const views = require('./views'); const routines = require('./routines'); +const routineModifications = require('./routineModifications'); module.exports = { columns, tableModifications, + viewModifications, primaryKeys, foreignKeys, views, routines, + routineModifications, }; diff --git a/packages/engines/postgres/sql/primaryKeys.js b/packages/engines/postgres/sql/primaryKeys.js index f73bbc66..204ff847 100644 --- a/packages/engines/postgres/sql/primaryKeys.js +++ b/packages/engines/postgres/sql/primaryKeys.js @@ -12,6 +12,6 @@ where and table_constraints.table_schema <> 'pg_catalog' and table_constraints.table_schema !~ '^pg_toast' and table_constraints.constraint_type = 'PRIMARY KEY' - and 'table:' || table_constraints.table_schema || '.' || table_constraints.table_name =[OBJECT_ID_CONDITION] + and 'tables:' || table_constraints.table_schema || '.' || table_constraints.table_name =OBJECT_ID_CONDITION order by key_column_usage.ordinal_position `; diff --git a/packages/engines/postgres/sql/routineModifications.js b/packages/engines/postgres/sql/routineModifications.js new file mode 100644 index 00000000..879a1195 --- /dev/null +++ b/packages/engines/postgres/sql/routineModifications.js @@ -0,0 +1,10 @@ +module.exports = ` +select + routine_name as "pureName", + routine_schema as "schemaName", + md5(routine_definition) as "hashCode", + routine_type as "objectType" +from + information_schema.routines where routine_schema != 'information_schema' and routine_schema != 'pg_catalog' + and routine_type in ('PROCEDURE', 'FUNCTION') +`; diff --git a/packages/engines/postgres/sql/routines.js b/packages/engines/postgres/sql/routines.js index 16e3bdd4..80c18960 100644 --- a/packages/engines/postgres/sql/routines.js +++ b/packages/engines/postgres/sql/routines.js @@ -6,5 +6,10 @@ select md5(routine_definition) as "hashCode", routine_type as "objectType" from - information_schema.routines where routine_schema != 'information_schema' and routine_schema != 'pg_catalog' and routine_type is not null + information_schema.routines where routine_schema != 'information_schema' and routine_schema != 'pg_catalog' + and ( + (routine_type = 'PROCEDURE' and ('procedures:' || routine_schema || '.' || routine_schema) =OBJECT_ID_CONDITION) + or + (routine_type = 'FUNCTION' and ('functions:' || routine_schema || '.' || routine_schema) =OBJECT_ID_CONDITION) + ) `; diff --git a/packages/engines/postgres/sql/tableModifications.js b/packages/engines/postgres/sql/tableModifications.js index bb403579..b34bf292 100644 --- a/packages/engines/postgres/sql/tableModifications.js +++ b/packages/engines/postgres/sql/tableModifications.js @@ -20,7 +20,7 @@ SELECT oid as "objectId", nspname as "schemaName", relname as "pureName", ' ' || column_name || ' ' || type || ' '|| not_null ) , E',\\n' - ) || E'\\n);\\n' || (select pkey from pkey where pkey.conrelid = oid)) as "hashCode" + ) || E'\\n);\\n' || coalesce((select pkey from pkey where pkey.conrelid = oid),'NO_PK')) as "hashCode" from ( SELECT @@ -47,6 +47,6 @@ from AND n.nspname !~ '^pg_toast' ORDER BY a.attnum ) as tabledefinition -where 'table:' || nspname || '.' || relname =[OBJECT_ID_CONDITION] +where ('tables:' || nspname || '.' || relname) =OBJECT_ID_CONDITION group by relname, nspname, oid `; diff --git a/packages/engines/postgres/sql/viewModifications.js b/packages/engines/postgres/sql/viewModifications.js new file mode 100644 index 00000000..a74c01a3 --- /dev/null +++ b/packages/engines/postgres/sql/viewModifications.js @@ -0,0 +1,8 @@ +module.exports = ` +select + table_name as "pureName", + table_schema as "schemaName", + md5(view_definition) as "hashCode" +from + information_schema.views where table_schema != 'information_schema' and table_schema != 'pg_catalog' +`; diff --git a/packages/engines/postgres/sql/views.js b/packages/engines/postgres/sql/views.js index bc72e1ae..8d18ee55 100644 --- a/packages/engines/postgres/sql/views.js +++ b/packages/engines/postgres/sql/views.js @@ -5,5 +5,7 @@ select view_definition as "createSql", md5(view_definition) as "hashCode" from - information_schema.views where table_schema != 'information_schema' and table_schema != 'pg_catalog' + information_schema.views +where table_schema != 'information_schema' and table_schema != 'pg_catalog' + and ('views:' || table_schema || '.' || table_name) =OBJECT_ID_CONDITION `;