From 6188e903400146e287cba3a0bd4a8218946c2916 Mon Sep 17 00:00:00 2001 From: Jan Prochazka Date: Sun, 2 Feb 2020 19:27:25 +0100 Subject: [PATCH] dialect, dumper --- api/src/dmlf/command.js | 13 +++++ api/src/dmlf/select.js | 37 +++++++++++++ api/src/engines/default/SqlDumper.js | 64 +++++++++++++++++++++++ api/src/engines/mssql/MsSqlDumper.js | 5 ++ api/src/engines/mssql/index.js | 20 ++++++- api/src/engines/mysql/MySqlAnalyser.js | 54 +++++++++++++++++++ api/src/engines/mysql/MySqlDumper.js | 5 ++ api/src/engines/mysql/columns.sql | 13 +++++ api/src/engines/mysql/index.js | 25 ++++++++- api/src/engines/mysql/tables.sql | 5 ++ api/src/engines/postgres/PostgreDumper.js | 5 ++ api/src/engines/postgres/index.js | 9 ++++ api/src/proc/databaseConnectionProcess.js | 12 ++++- types/dialect.d.ts | 5 ++ types/dumper.d.ts | 5 ++ types/engines.d.ts | 16 ++++-- types/index.d.ts | 2 + types/query.d.ts | 9 +++- 18 files changed, 294 insertions(+), 10 deletions(-) create mode 100644 api/src/dmlf/command.js create mode 100644 api/src/dmlf/select.js create mode 100644 api/src/engines/default/SqlDumper.js create mode 100644 api/src/engines/mssql/MsSqlDumper.js create mode 100644 api/src/engines/mysql/MySqlAnalyser.js create mode 100644 api/src/engines/mysql/MySqlDumper.js create mode 100644 api/src/engines/mysql/columns.sql create mode 100644 api/src/engines/mysql/tables.sql create mode 100644 api/src/engines/postgres/PostgreDumper.js create mode 100644 types/dialect.d.ts create mode 100644 types/dumper.d.ts diff --git a/api/src/dmlf/command.js b/api/src/dmlf/command.js new file mode 100644 index 00000000..78a6ce71 --- /dev/null +++ b/api/src/dmlf/command.js @@ -0,0 +1,13 @@ +class Command { + /** @param driver {import('dbgate').EngineDriver} */ + toSql(driver) { + const dumper = driver.createDumper(); + this.dumpSql(dumper); + return dumper.s; + } + + /** @param dumper {import('dbgate').SqlDumper} */ + dumpSql(dumper) {} +} + +module.exports = Command; diff --git a/api/src/dmlf/select.js b/api/src/dmlf/select.js new file mode 100644 index 00000000..deae22f8 --- /dev/null +++ b/api/src/dmlf/select.js @@ -0,0 +1,37 @@ +const Command = require('./command'); + +class Select extends Command { + constructor() { + super(); + /** @type {number} */ + this.topRecords = undefined; + /** @type {import('dbgate').NamedObjectInfo} */ + this.from = undefined; + /** @type {import('dbgate').RangeDefinition} */ + this.range = undefined; + this.distinct = false; + this.selectAll = false; + } + + /** @param dumper {import('dbgate').SqlDumper} */ + dumpSql(dumper) { + dumper.put('^select '); + if (this.topRecords) { + dumper.put('^top %s ', this.topRecords); + } + if (this.distinct) { + dumper.put('^distinct '); + } + if (this.selectAll) { + dumper.put('* '); + } else { + // TODO + } + dumper.put('^from %f ', this.from); + if (this.range) { + dumper.put('^limit %s ^offset %s ', this.range.limit, this.range.offset); + } + } +} + +module.exports = Select; diff --git a/api/src/engines/default/SqlDumper.js b/api/src/engines/default/SqlDumper.js new file mode 100644 index 00000000..82e02994 --- /dev/null +++ b/api/src/engines/default/SqlDumper.js @@ -0,0 +1,64 @@ +class SqlDumper { + /** @param driver {import('dbgate').EngineDriver} */ + constructor(driver) { + this.s = ''; + this.driver = driver; + this.dialect = driver.dialect; + } + putRaw(text) { + this.s += text; + } + putCmd(text) { + this.putRaw(text); + this.putRaw(';\n'); + } + putFormattedValue(c, value) { + switch (c) { + case 's': + if (value != null) { + this.putRaw(value.toString()); + } + break; + case 'f': + { + const { schemaName, pureName } = value; + if (schemaName) { + this.putRaw(this.dialect.quoteIdentifier(schemaName)); + this.putRaw('.'); + } + this.putRaw(this.dialect.quoteIdentifier(pureName)); + } + break; + } + } + /** @param format {string} */ + put(format, ...args) { + let i = 0; + let argIndex = 0; + const length = format.length; + while (i < length) { + let c = format[i]; + i++; + switch (c) { + case '^': + while (i < length && format[i].match(/[a-z]/i)) { + this.putRaw(format[i].toUpperCase()); + i++; + } + break; + case '%': + c = format[i]; + i++; + this.putFormattedValue(c, args[argIndex]); + argIndex++; + break; + + default: + this.putRaw(c); + break; + } + } + } +} + +module.exports = SqlDumper; diff --git a/api/src/engines/mssql/MsSqlDumper.js b/api/src/engines/mssql/MsSqlDumper.js new file mode 100644 index 00000000..d44e23cf --- /dev/null +++ b/api/src/engines/mssql/MsSqlDumper.js @@ -0,0 +1,5 @@ +const SqlDumper = require('../default/SqlDumper'); + +class MsSqlDumper extends SqlDumper {} + +module.exports = MsSqlDumper; diff --git a/api/src/engines/mssql/index.js b/api/src/engines/mssql/index.js index 55bffbb8..30fae864 100644 --- a/api/src/engines/mssql/index.js +++ b/api/src/engines/mssql/index.js @@ -1,8 +1,18 @@ const _ = require('lodash'); const mssql = require('mssql'); const MsSqlAnalyser = require('./MsSqlAnalyser'); +const MsSqlDumper = require('./MsSqlDumper'); -module.exports = { +/** @type {import('dbgate').SqlDialect} */ +const dialect = { + limitSelect: true, + quoteIdentifier(s) { + return `[${s}]`; + }, +}; + +/** @type {import('dbgate').EngineDriver} */ +const driver = { async connect({ server, port, user, password, database }) { const pool = await mssql.connect({ server, port, user, password, database }); return pool; @@ -26,5 +36,11 @@ module.exports = { await analyser.runAnalysis(); return analyser.result; }, - async analyseIncremental(pool) {}, + // async analyseIncremental(pool) {}, + createDumper() { + return new MsSqlDumper(this); + }, + dialect, }; + +module.exports = driver; diff --git a/api/src/engines/mysql/MySqlAnalyser.js b/api/src/engines/mysql/MySqlAnalyser.js new file mode 100644 index 00000000..64406040 --- /dev/null +++ b/api/src/engines/mysql/MySqlAnalyser.js @@ -0,0 +1,54 @@ +const fs = require('fs-extra'); +const fp = require('lodash/fp'); +const path = require('path'); +const _ = require('lodash'); + +const DatabaseAnalayser = require('../default/DatabaseAnalyser'); + +/** @returns {Promise} */ +async function loadQuery(name) { + return await fs.readFile(path.join(__dirname, name), 'utf-8'); +} + +class MySqlAnalyser extends DatabaseAnalayser { + constructor(pool, driver) { + super(pool, driver); + } + + async createQuery( + resFileName, + tables = false, + views = false, + procedures = false, + functions = false, + triggers = false + ) { + console.log('DB', this.pool._database_name); + let res = await loadQuery(resFileName); + res = res.replace('=[OBJECT_NAME_CONDITION]', ' is not null'); + res = res.replace('#DATABASE#', this.pool._database_name); + return res; + } + async runAnalysis() { + const tables = await this.driver.query(this.pool, await this.createQuery('tables.sql')); + const columns = await this.driver.query(this.pool, await this.createQuery('columns.sql')); + // const pkColumns = await this.driver.query(this.pool, await this.createQuery('primary_keys.sql')); + // const fkColumns = await this.driver.query(this.pool, await this.createQuery('foreign_keys.sql')); + + this.result.tables = tables.rows.map(table => ({ + ...table, + columns: columns.rows + .filter(col => col.objectId == table.objectId) + .map(({ isNullable, extra, ...col }) => ({ + ...col, + notNull: !isNullable, + autoIncrement: extra && extra.toLowerCase().includes('auto_increment'), + })), + foreignKeys: [], + // primaryKey: extractPrimaryKeys(table, pkColumns.rows), + // foreignKeys: extractForeignKeys(table, fkColumns.rows), + })); + } +} + +module.exports = MySqlAnalyser; diff --git a/api/src/engines/mysql/MySqlDumper.js b/api/src/engines/mysql/MySqlDumper.js new file mode 100644 index 00000000..4dc3d71d --- /dev/null +++ b/api/src/engines/mysql/MySqlDumper.js @@ -0,0 +1,5 @@ +const SqlDumper = require('../default/SqlDumper'); + +class MySqlDumper extends SqlDumper {} + +module.exports = MySqlDumper; diff --git a/api/src/engines/mysql/columns.sql b/api/src/engines/mysql/columns.sql new file mode 100644 index 00000000..3271b108 --- /dev/null +++ b/api/src/engines/mysql/columns.sql @@ -0,0 +1,13 @@ +select + TABLE_NAME as pureName, + COLUMN_NAME as columnName, + IS_NULLABLE as isNullable, + DATA_TYPE as dataType, + CHARACTER_MAXIMUM_LENGTH, + NUMERIC_PRECISION, + NUMERIC_SCALE, + COLUMN_DEFAULT, + EXTRA as extra +from INFORMATION_SCHEMA.COLUMNS +where TABLE_SCHEMA = '#DATABASE#' and TABLE_NAME =[OBJECT_NAME_CONDITION] +order by ORDINAL_POSITION diff --git a/api/src/engines/mysql/index.js b/api/src/engines/mysql/index.js index 2fc9a417..dc893e79 100644 --- a/api/src/engines/mysql/index.js +++ b/api/src/engines/mysql/index.js @@ -1,8 +1,20 @@ const mysql = require('mysql'); +const MySqlAnalyser = require('./MySqlAnalyser'); +const MySqlDumper = require('./MySqlDumper'); -module.exports = { +/** @type {import('dbgate').SqlDialect} */ +const dialect = { + rangeSelect: true, + quoteIdentifier(s) { + return '`' + s + '`'; + }, +}; + +/** @type {import('dbgate').EngineDriver} */ +const driver = { async connect({ server, port, user, password, database }) { const connection = mysql.createConnection({ host: server, port, user, password, database }); + connection._database_name = database; return connection; }, async query(connection, sql) { @@ -18,8 +30,19 @@ module.exports = { const version = rows[0].Value; return { version }; }, + async analyseFull(pool) { + const analyser = new MySqlAnalyser(pool, this); + await analyser.runAnalysis(); + return analyser.result; + }, async listDatabases(connection) { const { rows } = await this.query(connection, 'show databases'); return rows.map(x => ({ name: x.Database })); }, + createDumper() { + return new MySqlDumper(this); + }, + dialect, }; + +module.exports = driver; diff --git a/api/src/engines/mysql/tables.sql b/api/src/engines/mysql/tables.sql new file mode 100644 index 00000000..51f4f7f5 --- /dev/null +++ b/api/src/engines/mysql/tables.sql @@ -0,0 +1,5 @@ +select + TABLE_NAME as pureName, + case when ENGINE='InnoDB' then CREATE_TIME else coalesce(UPDATE_TIME, CREATE_TIME) end as alterTime +from information_schema.tables +where TABLE_SCHEMA = '#DATABASE#' and TABLE_NAME =[OBJECT_NAME_CONDITION]; diff --git a/api/src/engines/postgres/PostgreDumper.js b/api/src/engines/postgres/PostgreDumper.js new file mode 100644 index 00000000..15059534 --- /dev/null +++ b/api/src/engines/postgres/PostgreDumper.js @@ -0,0 +1,5 @@ +const SqlDumper = require('../default/SqlDumper'); + +class PostgreDumper extends SqlDumper {} + +module.exports = PostgreDumper; diff --git a/api/src/engines/postgres/index.js b/api/src/engines/postgres/index.js index b1484044..84fca42c 100644 --- a/api/src/engines/postgres/index.js +++ b/api/src/engines/postgres/index.js @@ -1,5 +1,13 @@ const { Client } = require('pg'); +/** @type {import('dbgate').SqlDialect} */ +const dialect = { + rangeSelect: true, + quoteIdentifier(s) { + return '"' + s + '"'; + }, +}; + module.exports = { async connect({ server, port, user, password, database }) { const client = new Client({ host: server, port, user, password, database: database || 'postgres' }); @@ -19,4 +27,5 @@ module.exports = { const { rows } = await this.query(client, 'SELECT datname AS name FROM pg_database WHERE datistemplate = false'); return rows; }, + dialect, }; diff --git a/api/src/proc/databaseConnectionProcess.js b/api/src/proc/databaseConnectionProcess.js index 67426c13..a55af872 100644 --- a/api/src/proc/databaseConnectionProcess.js +++ b/api/src/proc/databaseConnectionProcess.js @@ -1,4 +1,5 @@ const engines = require('../engines'); +const Select = require('../dmlf/select'); let systemConnection; let storedConnection; @@ -33,7 +34,16 @@ function waitConnected() { async function handleTableData({ msgid, schemaName, pureName }) { await waitConnected(); const driver = engines(storedConnection); - const res = await driver.query(systemConnection, `SELECT TOP(100) * FROM ${pureName}`); + + const select = new Select(); + if (driver.dialect.limitSelect) select.topRecords = 100; + if (driver.dialect.rangeSelect) select.range = { offset: 0, limit: 100 }; + select.from = { schemaName, pureName }; + select.selectAll = true; + const sql = select.toSql(driver); + console.log('SQL', sql); + const res = await driver.query(systemConnection, sql); + process.send({ msgtype: 'response', msgid, ...res }); } diff --git a/types/dialect.d.ts b/types/dialect.d.ts new file mode 100644 index 00000000..e0c5b06a --- /dev/null +++ b/types/dialect.d.ts @@ -0,0 +1,5 @@ +export interface SqlDialect { + rangeSelect?: boolean; + limitSelect?: boolean; + quoteIdentifier(s: string): string; +} diff --git a/types/dumper.d.ts b/types/dumper.d.ts new file mode 100644 index 00000000..f3aab2db --- /dev/null +++ b/types/dumper.d.ts @@ -0,0 +1,5 @@ +export interface SqlDumper { + s: string; + put(format: string, ...args); + putCmd(format: string, ...args); +} diff --git a/types/engines.d.ts b/types/engines.d.ts index a05365a3..c7b8ee57 100644 --- a/types/engines.d.ts +++ b/types/engines.d.ts @@ -1,18 +1,24 @@ import { QueryResult } from "./query"; +import { SqlDialect } from "./dialect"; +import { SqlDumper } from "./dumper"; +import { DatabaseInfo } from "./dbinfo"; + export interface EngineDriver { connect({ server, port, user, - password + password, + database }: { server: any; port: any; user: any; password: any; + database: any; }): any; query(pool: any, sql: string): Promise; - getVersion(pool: any): Promise; + getVersion(pool: any): Promise<{ version: string }>; listDatabases( pool: any ): Promise< @@ -20,6 +26,8 @@ export interface EngineDriver { name: string; }[] >; - analyseFull(pool: any): Promise; - analyseIncremental(pool: any): Promise; + analyseFull(pool: any): Promise; + // analyseIncremental(pool: any): Promise; + dialect: SqlDialect; + createDumper(): SqlDumper; } diff --git a/types/index.d.ts b/types/index.d.ts index 17d18d0b..a5356c50 100644 --- a/types/index.d.ts +++ b/types/index.d.ts @@ -9,3 +9,5 @@ export interface OpenedDatabaseConnection { export * from "./engines"; export * from "./dbinfo"; export * from "./query"; +export * from "./dialect"; +export * from "./dumper"; diff --git a/types/query.d.ts b/types/query.d.ts index b18e8fe7..1080e57b 100644 --- a/types/query.d.ts +++ b/types/query.d.ts @@ -1,3 +1,8 @@ -export interface QueryResult { - rows: any[]; +export interface RangeDefinition { + offset: number; + limit: number; +} + +export interface QueryResult { + rows: any[]; }