From a67071e28470bcbd0ec26780bb86f3c65750ded8 Mon Sep 17 00:00:00 2001 From: Fabio Di Stasio Date: Mon, 21 Mar 2022 18:32:45 +0100 Subject: [PATCH 1/9] feat(PostgreSQL): export tables --- package.json | 1 + src/common/customizations/postgresql.js | 4 +- src/main/libs/clients/PostgreSQLClient.js | 2 +- .../libs/exporters/sql/PostgreSQLExporter.js | 486 ++++++++++++++++++ src/main/workers/exporter.js | 6 +- src/renderer/components/ModalExportSchema.vue | 6 +- 6 files changed, 499 insertions(+), 6 deletions(-) create mode 100644 src/main/libs/exporters/sql/PostgreSQLExporter.js diff --git a/package.json b/package.json index 2ca547b4..5bc451af 100644 --- a/package.json +++ b/package.json @@ -120,6 +120,7 @@ "moment": "^2.29.1", "mysql2": "^2.3.2", "pg": "^8.7.1", + "pg-query-stream": "^4.2.3", "pgsql-ast-parser": "^7.2.1", "source-map-support": "^0.5.20", "spectre.css": "^0.5.9", diff --git a/src/common/customizations/postgresql.js b/src/common/customizations/postgresql.js index 178eee93..9d8f1936 100644 --- a/src/common/customizations/postgresql.js +++ b/src/common/customizations/postgresql.js @@ -31,9 +31,9 @@ module.exports = { routineAdd: true, functionAdd: true, schemaDrop: true, + schemaExport: true, + schemaImport: true, databaseEdit: false, - schemaExport: false, - schemaImport: false, tableSettings: true, viewSettings: true, triggerSettings: true, diff --git a/src/main/libs/clients/PostgreSQLClient.js b/src/main/libs/clients/PostgreSQLClient.js index d666bccd..39f8d19f 100644 --- a/src/main/libs/clients/PostgreSQLClient.js +++ b/src/main/libs/clients/PostgreSQLClient.js @@ -570,7 +570,7 @@ export class PostgreSQLClient extends AntaresCore { * @memberof MySQLClient */ async dropSchema (params) { - return await this.raw(`DROP SCHEMA "${params.database}"`); + return await this.raw(`DROP SCHEMA "${params.database}" CASCADE`); } /** diff --git a/src/main/libs/exporters/sql/PostgreSQLExporter.js b/src/main/libs/exporters/sql/PostgreSQLExporter.js new file mode 100644 index 00000000..4fbb9f94 --- /dev/null +++ b/src/main/libs/exporters/sql/PostgreSQLExporter.js @@ -0,0 +1,486 @@ +import { SqlExporter } from './SqlExporter'; +import { BLOB, BIT, DATE, DATETIME, FLOAT, SPATIAL, IS_MULTI_SPATIAL, NUMBER } from 'common/fieldTypes'; +import hexToBinary from 'common/libs/hexToBinary'; +import { getArrayDepth } from 'common/libs/getArrayDepth'; +import moment from 'moment'; +import { lineString, point, polygon } from '@turf/helpers'; +import QueryStream from 'pg-query-stream'; + +export default class PostgreSQLExporter extends SqlExporter { + async getSqlHeader () { + let dump = await super.getSqlHeader(); + dump += ` + + +SET statement_timeout = 0; +SET lock_timeout = 0; +SET idle_in_transaction_session_timeout = 0; +SET client_encoding = 'UTF8'; +SET standard_conforming_strings = on; +SELECT pg_catalog.set_config('search_path', '', false); +SET check_function_bodies = false; +SET xmloption = content; +SET client_min_messages = warning; +SET row_security = off;`; + + return dump; + } + + async getCreateTable (tableName) { + let createSql = ''; + const sequences = []; + const columnsSql = []; + + // Table columns + const { rows } = await this._client + .select('*') + .schema('information_schema') + .from('columns') + .where({ table_schema: `= '${this.schemaName}'`, table_name: `= '${tableName}'` }) + .orderBy({ ordinal_position: 'ASC' }) + .run(); + + if (!rows.length) return ''; + + for (const column of rows) { + const columnArr = [ + `"${column.column_name}"`, + `${column.data_type}${column.character_maximum_length ? `(${column.character_maximum_length})` : ''}` + ]; + + if (column.column_default) { + columnArr.push(`DEFAULT ${column.column_default}`); + if (column.column_default.includes('nextval')) { + let sequenceName = column.column_default.split('\'')[1]; + if (sequenceName.includes('.')) sequenceName = sequenceName.split('.')[1]; + sequences.push(sequenceName); + } + } + if (column.is_nullable === 'NO') columnArr.push('NOT NULL'); + + columnsSql.push(columnArr.join(' ')); + } + + // Table sequences + for (const sequence of sequences) { + const { rows } = await this._client + .select('*') + .schema('information_schema') + .from('sequences') + .where({ sequence_schema: `= '${this.schemaName}'`, sequence_name: `= '${sequence}'` }) + .run(); + + if (rows.length) { + createSql += `CREATE SEQUENCE "${this.schemaName}"."${sequence}" + START WITH ${rows[0].start_value} + INCREMENT BY ${rows[0].increment} + MINVALUE ${rows[0].minimum_value} + MAXVALUE ${rows[0].maximum_value} + CACHE 1;\n`; + + createSql += `\nALTER TABLE "${this.schemaName}"."${sequence}" OWNER TO ${this._client._params.user};\n\n`; + } + } + + // Table create + createSql += `CREATE TABLE "${this.schemaName}"."${tableName}"( + ${columnsSql.join(',\n ')} +);\n`; + + createSql += `\nALTER TABLE "${this.schemaName}"."${tableName}" OWNER TO ${this._client._params.user};\n\n`; + + // Table indexes + const { rows: indexes } = await this._client + .select('*') + .schema('pg_catalog') + .from('pg_indexes') + .where({ schemaname: `= '${this.schemaName}'`, tablename: `= '${tableName}'` }) + .run(); + + for (const index of indexes) + createSql += `${index.indexdef};\n`; + + // Table foreigns + const { rows: foreigns } = await this._client.raw(` + SELECT + tc.table_schema, + tc.constraint_name, + tc.table_name, + kcu.column_name, + ccu.table_schema AS foreign_table_schema, + ccu.table_name AS foreign_table_name, + ccu.column_name AS foreign_column_name, + rc.update_rule, + rc.delete_rule + FROM information_schema.table_constraints AS tc + JOIN information_schema.key_column_usage AS kcu + ON tc.constraint_name = kcu.constraint_name + AND tc.table_schema = kcu.table_schema + JOIN information_schema.constraint_column_usage AS ccu + ON ccu.constraint_name = tc.constraint_name + AND ccu.table_schema = tc.table_schema + JOIN information_schema.referential_constraints AS rc + ON rc.constraint_name = kcu.constraint_name + WHERE tc.constraint_type = 'FOREIGN KEY' AND tc.table_schema = '${this.schemaName}' + AND tc.table_name = '${tableName}' + `); + + for (const foreign of foreigns) { + createSql += `\nALTER TABLE ONLY "${this.schemaName}"."${tableName}" + ADD CONSTRAINT "${foreign.constraint_name}" FOREIGN KEY ("${foreign.column_name}") REFERENCES "${foreign.table_schema}"."${foreign.table_name}" ("${foreign.foreign_column_name}") ON UPDATE ${foreign.update_rule} ON DELETE ${foreign.delete_rule};\n`; + } + + return createSql; + } + + getDropTable (tableName) { + return `DROP TABLE IF EXISTS "${tableName}";`; + } + + async * getTableInsert (tableName) { + let rowCount = 0; + let sqlStr = ''; + + const countResults = await this._client.raw(`SELECT COUNT(1) as count FROM "${this.schemaName}"."${tableName}"`); + if (countResults.rows.length === 1) rowCount = countResults.rows[0].count; + + if (rowCount > 0) { + let queryLength = 0; + let rowsWritten = 0; + const { sqlInsertDivider, sqlInsertAfter } = this._options; + const columns = await this._client.getTableColumns({ + table: tableName, + schema: this.schemaName + }); + + const notGeneratedColumns = columns.filter(col => !col.generated); + const columnNames = notGeneratedColumns.map(col => '"' + col.name + '"').join(', '); + + yield sqlStr; + + const stream = await this._queryStream( + `SELECT ${columnNames} FROM "${this.schemaName}"."${tableName}"` + ); + + for await (const row of stream) { + if (this.isCancelled) { + stream.destroy(); + yield null; + return; + } + + let sqlInsertString = `\nINSERT INTO "${tableName}" (${columnNames}) VALUES`; + + if ( + (sqlInsertDivider === 'bytes' && queryLength >= sqlInsertAfter * 1024) || + (sqlInsertDivider === 'rows' && rowsWritten === sqlInsertAfter) + ) { + queryLength = 0; + rowsWritten = 0; + } + + sqlInsertString += ' ('; + + for (const i in notGeneratedColumns) { + const column = notGeneratedColumns[i]; + const val = row[column.name]; + + if (val === null) sqlInsertString += 'NULL'; + else if (DATE.includes(column.type)) { + sqlInsertString += moment(val).isValid() + ? this.escapeAndQuote(moment(val).format('YYYY-MM-DD')) + : val; + } + else if (DATETIME.includes(column.type)) { + let datePrecision = ''; + for (let i = 0; i < column.precision; i++) + datePrecision += i === 0 ? '.S' : 'S'; + + sqlInsertString += moment(val).isValid() + ? this.escapeAndQuote(moment(val).format(`YYYY-MM-DD HH:mm:ss${datePrecision}`)) + : this.escapeAndQuote(val); + } + else if (BIT.includes(column.type)) + sqlInsertString += `b'${hexToBinary(Buffer.from(val).toString('hex'))}'`; + else if (BLOB.includes(column.type)) + sqlInsertString += `X'${val.toString('hex').toUpperCase()}'`; + else if (NUMBER.includes(column.type)) + sqlInsertString += val; + else if (FLOAT.includes(column.type)) + sqlInsertString += parseFloat(val); + else if (SPATIAL.includes(column.type)) { + let geoJson; + if (IS_MULTI_SPATIAL.includes(column.type)) { + const features = []; + for (const element of val) + features.push(this.getMarkers(element)); + + geoJson = { + type: 'FeatureCollection', + features + }; + } + else + geoJson = this._getGeoJSON(val); + + sqlInsertString += `ST_GeomFromGeoJSON('${JSON.stringify(geoJson)}')`; + } + else if (val === '') sqlInsertString += '\'\''; + else { + sqlInsertString += typeof val === 'string' + ? this.escapeAndQuote(val) + : typeof val === 'object' + ? this.escapeAndQuote(JSON.stringify(val)) + : val; + } + + if (parseInt(i) !== notGeneratedColumns.length - 1) + sqlInsertString += ', '; + } + + sqlInsertString += ');'; + + queryLength += sqlInsertString.length; + rowsWritten++; + yield sqlInsertString; + } + + sqlStr = ';\n\n'; + + yield sqlStr; + } + } + + async getViews () { + const { rows: views } = await this._client.raw( + `SHOW TABLE STATUS FROM \`${this.schemaName}\` WHERE Comment = 'VIEW'` + ); + let sqlString = ''; + + for (const view of views) { + sqlString += `DROP VIEW IF EXISTS \`${view.Name}\`;\n`; + const viewSyntax = await this.getCreateTable(view.Name); + sqlString += viewSyntax.replaceAll('`' + this.schemaName + '`.', ''); + sqlString += '\n'; + } + + return sqlString; + } + + async getTriggers () { + const { rows: triggers } = await this._client.raw( + `SHOW TRIGGERS FROM \`${this.schemaName}\`` + ); + const generatedTables = this._tables + .filter(t => t.includeStructure) + .map(t => t.table); + + let sqlString = ''; + + for (const trigger of triggers) { + const { + Trigger: name, + Timing: timing, + Event: event, + Table: table, + Statement: statement, + sql_mode: sqlMode + } = trigger; + + if (!generatedTables.includes(table)) continue; + + const definer = this.getEscapedDefiner(trigger.Definer); + sqlString += '/*!50003 SET @OLD_SQL_MODE=@@SQL_MODE*/;;\n'; + sqlString += `/*!50003 SET SQL_MODE="${sqlMode}" */;\n`; + sqlString += 'DELIMITER ;;\n'; + sqlString += '/*!50003 CREATE*/ '; + sqlString += `/*!50017 DEFINER=${definer}*/ `; + sqlString += `/*!50003 TRIGGER \`${name}\` ${timing} ${event} ON \`${table}\` FOR EACH ROW ${statement}*/;;\n`; + sqlString += 'DELIMITER ;\n'; + sqlString += '/*!50003 SET SQL_MODE=@OLD_SQL_MODE */;\n\n'; + } + + return sqlString; + } + + async getSchedulers () { + const { rows: schedulers } = await this._client.raw( + `SELECT *, EVENT_SCHEMA AS \`Db\`, EVENT_NAME AS \`Name\` FROM information_schema.\`EVENTS\` WHERE EVENT_SCHEMA = '${this.schemaName}'` + ); + let sqlString = ''; + + for (const scheduler of schedulers) { + const { + EVENT_NAME: name, + SQL_MODE: sqlMode, + EVENT_TYPE: type, + INTERVAL_VALUE: intervalValue, + INTERVAL_FIELD: intervalField, + STARTS: starts, + ENDS: ends, + EXECUTE_AT: at, + ON_COMPLETION: onCompletion, + STATUS: status, + EVENT_DEFINITION: definition + } = scheduler; + + const definer = this.getEscapedDefiner(scheduler.DEFINER); + const comment = this.escapeAndQuote(scheduler.EVENT_COMMENT); + + sqlString += `/*!50106 DROP EVENT IF EXISTS \`${name}\` */;\n`; + sqlString += '/*!50003 SET @OLD_SQL_MODE=@@SQL_MODE*/;;\n'; + sqlString += `/*!50003 SET SQL_MODE='${sqlMode}' */;\n`; + sqlString += 'DELIMITER ;;\n'; + sqlString += '/*!50106 CREATE*/ '; + sqlString += `/*!50117 DEFINER=${definer}*/ `; + sqlString += `/*!50106 EVENT \`${name}\` ON SCHEDULE `; + if (type === 'RECURRING') { + sqlString += `EVERY ${intervalValue} ${intervalField} STARTS '${starts}' `; + + if (ends) sqlString += `ENDS '${ends}' `; + } + else sqlString += `AT '${at}' `; + sqlString += `ON COMPLETION ${onCompletion} ${ + status === 'disabled' ? 'DISABLE' : 'ENABLE' + } COMMENT ${comment || '\'\''} DO ${definition}*/;;\n`; + sqlString += 'DELIMITER ;\n'; + sqlString += '/*!50003 SET SQL_MODE=@OLD_SQL_MODE*/;;\n'; + } + + return sqlString; + } + + async getFunctions () { + const { rows: functions } = await this._client.raw( + `SHOW FUNCTION STATUS WHERE \`Db\` = '${this.schemaName}';` + ); + + let sqlString = ''; + + for (const func of functions) { + const definer = this.getEscapedDefiner(func.Definer); + sqlString += await this.getRoutineSyntax( + func.Name, + func.Type, + definer + ); + } + + return sqlString; + } + + async getRoutines () { + const { rows: routines } = await this._client.raw( + `SHOW PROCEDURE STATUS WHERE \`Db\` = '${this.schemaName}';` + ); + + let sqlString = ''; + + for (const routine of routines) { + const definer = this.getEscapedDefiner(routine.Definer); + + sqlString += await this.getRoutineSyntax( + routine.Name, + routine.Type, + definer + ); + } + + return sqlString; + } + + async getRoutineSyntax (name, type, definer) { + const { rows: routines } = await this._client.raw( + `SHOW CREATE ${type} \`${this.schemaName}\`.\`${name}\`` + ); + + if (routines.length === 0) return ''; + + const routine = routines[0]; + + const fieldName = `Create ${type === 'PROCEDURE' ? 'Procedure' : 'Function'}`; + const sqlMode = routine.sql_mode; + const createProcedure = routine[fieldName]; + let sqlString = ''; + + if (createProcedure) { // If procedure body not empty + const startOffset = createProcedure.indexOf(type); + const procedureBody = createProcedure.substring(startOffset); + + sqlString += `/*!50003 DROP ${type} IF EXISTS ${name}*/;;\n`; + sqlString += '/*!50003 SET @OLD_SQL_MODE=@@SQL_MODE*/;;\n'; + sqlString += `/*!50003 SET SQL_MODE="${sqlMode}"*/;;\n`; + sqlString += 'DELIMITER ;;\n'; + sqlString += `/*!50003 CREATE*/ /*!50020 DEFINER=${definer}*/ /*!50003 ${procedureBody}*/;;\n`; + sqlString += 'DELIMITER ;\n'; + sqlString += '/*!50003 SET SQL_MODE=@OLD_SQL_MODE*/;\n'; + } + + return sqlString; + } + + async getCreateType () {} + + async _queryStream (sql) { + if (process.env.NODE_ENV === 'development') console.log('EXPORTER:', sql); + const connection = await this._client.getConnection(); + const query = new QueryStream(sql, null); + const stream = connection.query(query); + const dispose = () => connection.end(); + + stream.on('end', dispose); + stream.on('error', dispose); + stream.on('close', dispose); + return stream; + } + + getEscapedDefiner (definer) { + return definer + .split('@') + .map(part => '`' + part + '`') + .join('@'); + } + + escapeAndQuote (val) { + // eslint-disable-next-line no-control-regex + const CHARS_TO_ESCAPE = /[\0\b\t\n\r\x1a"'\\]/g; + const CHARS_ESCAPE_MAP = { + '\0': '\\0', + '\b': '\\b', + '\t': '\\t', + '\n': '\\n', + '\r': '\\r', + '\x1a': '\\Z', + '"': '\\"', + '\'': '\\\'', + '\\': '\\\\' + }; + let chunkIndex = CHARS_TO_ESCAPE.lastIndex = 0; + let escapedVal = ''; + let match; + + while ((match = CHARS_TO_ESCAPE.exec(val))) { + escapedVal += val.slice(chunkIndex, match.index) + CHARS_ESCAPE_MAP[match[0]]; + chunkIndex = CHARS_TO_ESCAPE.lastIndex; + } + + if (chunkIndex === 0) + return `'${val}'`; + + if (chunkIndex < val.length) + return `'${escapedVal + val.slice(chunkIndex)}'`; + + return `'${escapedVal}'`; + } + + _getGeoJSON (val) { + if (Array.isArray(val)) { + if (getArrayDepth(val) === 1) + return lineString(val.reduce((acc, curr) => [...acc, [curr.x, curr.y]], [])); + else + return polygon(val.map(arr => arr.reduce((acc, curr) => [...acc, [curr.x, curr.y]], []))); + } + else + return point([val.x, val.y]); + } +} diff --git a/src/main/workers/exporter.js b/src/main/workers/exporter.js index 43a0aff0..ba67388d 100644 --- a/src/main/workers/exporter.js +++ b/src/main/workers/exporter.js @@ -1,6 +1,7 @@ +import fs from 'fs'; import { ClientsFactory } from '../libs/ClientsFactory'; import MysqlExporter from '../libs/exporters/sql/MysqlExporter.js'; -import fs from 'fs'; +import PostgreSQLExporter from '../libs/exporters/sql/PostgresqlExporter'; let exporter; process.on('message', async ({ type, client, tables, options }) => { @@ -17,6 +18,9 @@ process.on('message', async ({ type, client, tables, options }) => { case 'maria': exporter = new MysqlExporter(connection, tables, options); break; + case 'pg': + exporter = new PostgreSQLExporter(connection, tables, options); + break; default: process.send({ type: 'error', diff --git a/src/renderer/components/ModalExportSchema.vue b/src/renderer/components/ModalExportSchema.vue index 6b2c8810..4715ab53 100644 --- a/src/renderer/components/ModalExportSchema.vue +++ b/src/renderer/components/ModalExportSchema.vue @@ -190,7 +190,7 @@ :key="key" class="form-checkbox" > - {{ $t(`word.${key}`) }} + {{ $tc(`word.${key}`, 2) }}
@@ -353,8 +353,10 @@ export default { structure.forEach(feat => { const val = customizations[this.currentWorkspace.client][feat]; - if (val) + if (val) { + if (feat === 'triggerFunctions') feat = 'triggerFunction';// TODO: remove after l18n refactor this.$set(this.options.includes, feat, true); + } }); ipcRenderer.on('export-progress', this.updateProgress); From bb02479b71bf75a6e69e28af57c5fe213d3f30bc Mon Sep 17 00:00:00 2001 From: Fabio Di Stasio Date: Tue, 22 Mar 2022 12:40:14 +0100 Subject: [PATCH 2/9] feat(PostgreSQL): export user-defined types before tables --- .../libs/exporters/sql/PostgreSQLExporter.js | 85 +++++++++++++++---- src/main/workers/exporter.js | 2 +- 2 files changed, 71 insertions(+), 16 deletions(-) diff --git a/src/main/libs/exporters/sql/PostgreSQLExporter.js b/src/main/libs/exporters/sql/PostgreSQLExporter.js index 4fbb9f94..02ba887e 100644 --- a/src/main/libs/exporters/sql/PostgreSQLExporter.js +++ b/src/main/libs/exporters/sql/PostgreSQLExporter.js @@ -17,11 +17,13 @@ SET lock_timeout = 0; SET idle_in_transaction_session_timeout = 0; SET client_encoding = 'UTF8'; SET standard_conforming_strings = on; -SELECT pg_catalog.set_config('search_path', '', false); +-- SELECT pg_catalog.set_config('search_path', '', false); SET check_function_bodies = false; SET xmloption = content; SET client_min_messages = warning; -SET row_security = off;`; +SET row_security = off;\n\n\n`; + + dump += await this.getTypes(); return dump; } @@ -30,6 +32,15 @@ SET row_security = off;`; let createSql = ''; const sequences = []; const columnsSql = []; + const arrayTypes = { + _int2: 'smallint', + _int4: 'integer', + _int8: 'bigint', + _float4: 'real', + _float8: 'double precision', + _char: '"char"', + _varchar: 'character varying' + }; // Table columns const { rows } = await this._client @@ -43,9 +54,18 @@ SET row_security = off;`; if (!rows.length) return ''; for (const column of rows) { + let fieldType = column.data_type; + if (fieldType === 'USER-DEFINED') fieldType = column.udt_name; + else if (fieldType === 'ARRAY') { + if (Object.keys(arrayTypes).includes(fieldType)) + fieldType = arrayTypes[type] + '[]'; + else + fieldType = column.udt_name.replaceAll('_', '') + '[]'; + } + const columnArr = [ `"${column.column_name}"`, - `${column.data_type}${column.character_maximum_length ? `(${column.character_maximum_length})` : ''}` + `${fieldType}${column.character_maximum_length ? `(${column.character_maximum_length})` : ''}` ]; if (column.column_default) { @@ -71,25 +91,26 @@ SET row_security = off;`; .run(); if (rows.length) { - createSql += `CREATE SEQUENCE "${this.schemaName}"."${sequence}" + createSql += `CREATE SEQUENCE "${sequence}" START WITH ${rows[0].start_value} INCREMENT BY ${rows[0].increment} MINVALUE ${rows[0].minimum_value} MAXVALUE ${rows[0].maximum_value} CACHE 1;\n`; - createSql += `\nALTER TABLE "${this.schemaName}"."${sequence}" OWNER TO ${this._client._params.user};\n\n`; + // createSql += `\nALTER TABLE "${sequence}" OWNER TO ${this._client._params.user};\n\n`; } } // Table create - createSql += `CREATE TABLE "${this.schemaName}"."${tableName}"( + createSql += `\nCREATE TABLE "${tableName}"( ${columnsSql.join(',\n ')} );\n`; - createSql += `\nALTER TABLE "${this.schemaName}"."${tableName}" OWNER TO ${this._client._params.user};\n\n`; + // createSql += `\nALTER TABLE "${tableName}" OWNER TO ${this._client._params.user};\n\n`; // Table indexes + createSql += '\n'; const { rows: indexes } = await this._client .select('*') .schema('pg_catalog') @@ -126,7 +147,7 @@ SET row_security = off;`; `); for (const foreign of foreigns) { - createSql += `\nALTER TABLE ONLY "${this.schemaName}"."${tableName}" + createSql += `\nALTER TABLE ONLY "${tableName}" ADD CONSTRAINT "${foreign.constraint_name}" FOREIGN KEY ("${foreign.column_name}") REFERENCES "${foreign.table_schema}"."${foreign.table_name}" ("${foreign.foreign_column_name}") ON UPDATE ${foreign.update_rule} ON DELETE ${foreign.delete_rule};\n`; } @@ -141,7 +162,7 @@ SET row_security = off;`; let rowCount = 0; let sqlStr = ''; - const countResults = await this._client.raw(`SELECT COUNT(1) as count FROM "${this.schemaName}"."${tableName}"`); + const countResults = await this._client.raw(`SELECT COUNT(1) as count FROM "${tableName}"`); if (countResults.rows.length === 1) rowCount = countResults.rows[0].count; if (rowCount > 0) { @@ -159,7 +180,7 @@ SET row_security = off;`; yield sqlStr; const stream = await this._queryStream( - `SELECT ${columnNames} FROM "${this.schemaName}"."${tableName}"` + `SELECT ${columnNames} FROM "${tableName}"` ); for await (const row of stream) { @@ -169,7 +190,7 @@ SET row_security = off;`; return; } - let sqlInsertString = `\nINSERT INTO "${tableName}" (${columnNames}) VALUES`; + let sqlInsertString = `INSERT INTO "${tableName}" (${columnNames}) VALUES`; if ( (sqlInsertDivider === 'bytes' && queryLength >= sqlInsertAfter * 1024) || @@ -238,7 +259,7 @@ SET row_security = off;`; sqlInsertString += ', '; } - sqlInsertString += ');'; + sqlInsertString += ');\n'; queryLength += sqlInsertString.length; rowsWritten++; @@ -251,15 +272,49 @@ SET row_security = off;`; } } + async getTypes () { + let sqlString = ''; + const { rows: types } = await this._client.raw(` + SELECT pg_type.typname, pg_enum.enumlabel + FROM pg_type + JOIN pg_enum ON pg_enum.enumtypid = pg_type.oid; + `); + + if (types.length) { // TODO: refactor + sqlString += this.buildComment('Dump of types\n------------------------------------------------------------') + '\n\n'; + + const typesArr = types.reduce((arr, type) => { + if (arr.every(el => el.name !== type.typname)) + arr.push({ name: type.typname, enums: [this.escapeAndQuote(type.enumlabel)] }); + else { + const i = arr.findIndex(el => el.name === type.typname); + arr[i].enums.push(this.escapeAndQuote(type.enumlabel)); + } + + return arr; + }, []); + + for (const type of typesArr) { + sqlString += `CREATE TYPE "${type.name}" AS ENUM ( + ${type.enums.join(',\n\t')} +);`; + } + + // sqlString += `\nALTER TYPE "${tableName}" OWNER TO ${this._client._params.user};\n` + } + + return sqlString; + } + async getViews () { const { rows: views } = await this._client.raw( - `SHOW TABLE STATUS FROM \`${this.schemaName}\` WHERE Comment = 'VIEW'` + `SELECT * FROM "pg_views" WHERE "schemaname"='${this.schemaName}'` ); let sqlString = ''; for (const view of views) { - sqlString += `DROP VIEW IF EXISTS \`${view.Name}\`;\n`; - const viewSyntax = await this.getCreateTable(view.Name); + sqlString += `DROP VIEW IF EXISTS '${view.viewname}';\n`; + const viewSyntax = await this.getCreateTable(view.viewname); sqlString += viewSyntax.replaceAll('`' + this.schemaName + '`.', ''); sqlString += '\n'; } diff --git a/src/main/workers/exporter.js b/src/main/workers/exporter.js index ba67388d..7e96c78f 100644 --- a/src/main/workers/exporter.js +++ b/src/main/workers/exporter.js @@ -1,7 +1,7 @@ import fs from 'fs'; import { ClientsFactory } from '../libs/ClientsFactory'; import MysqlExporter from '../libs/exporters/sql/MysqlExporter.js'; -import PostgreSQLExporter from '../libs/exporters/sql/PostgresqlExporter'; +import PostgreSQLExporter from '../libs/exporters/sql/PostgreSQLExporter'; let exporter; process.on('message', async ({ type, client, tables, options }) => { From 86f011f34fec9d6829bce324493fea888a863ffc Mon Sep 17 00:00:00 2001 From: Fabio Di Stasio Date: Tue, 22 Mar 2022 12:59:13 +0100 Subject: [PATCH 3/9] feat(PostgreSQL): export views --- src/main/libs/exporters/sql/PostgreSQLExporter.js | 10 +++------- 1 file changed, 3 insertions(+), 7 deletions(-) diff --git a/src/main/libs/exporters/sql/PostgreSQLExporter.js b/src/main/libs/exporters/sql/PostgreSQLExporter.js index 02ba887e..4b41626d 100644 --- a/src/main/libs/exporters/sql/PostgreSQLExporter.js +++ b/src/main/libs/exporters/sql/PostgreSQLExporter.js @@ -160,7 +160,7 @@ SET row_security = off;\n\n\n`; async * getTableInsert (tableName) { let rowCount = 0; - let sqlStr = ''; + const sqlStr = ''; const countResults = await this._client.raw(`SELECT COUNT(1) as count FROM "${tableName}"`); if (countResults.rows.length === 1) rowCount = countResults.rows[0].count; @@ -266,8 +266,6 @@ SET row_security = off;\n\n\n`; yield sqlInsertString; } - sqlStr = ';\n\n'; - yield sqlStr; } } @@ -313,10 +311,8 @@ SET row_security = off;\n\n\n`; let sqlString = ''; for (const view of views) { - sqlString += `DROP VIEW IF EXISTS '${view.viewname}';\n`; - const viewSyntax = await this.getCreateTable(view.viewname); - sqlString += viewSyntax.replaceAll('`' + this.schemaName + '`.', ''); - sqlString += '\n'; + sqlString += `\nDROP VIEW IF EXISTS '${view.viewname}';\n`; + sqlString += `\nCREATE VIEW "${view.viewname}" AS \n${view.definition}\n`; } return sqlString; From 42376b4bc6dd8b630402d09b026d9fbc0b8646bb Mon Sep 17 00:00:00 2001 From: Fabio Di Stasio Date: Tue, 22 Mar 2022 17:25:34 +0100 Subject: [PATCH 4/9] feat(PostgreSQL): export triggers --- .../libs/exporters/sql/PostgreSQLExporter.js | 91 +++---------------- 1 file changed, 15 insertions(+), 76 deletions(-) diff --git a/src/main/libs/exporters/sql/PostgreSQLExporter.js b/src/main/libs/exporters/sql/PostgreSQLExporter.js index 4b41626d..cff70531 100644 --- a/src/main/libs/exporters/sql/PostgreSQLExporter.js +++ b/src/main/libs/exporters/sql/PostgreSQLExporter.js @@ -305,9 +305,7 @@ SET row_security = off;\n\n\n`; } async getViews () { - const { rows: views } = await this._client.raw( - `SELECT * FROM "pg_views" WHERE "schemaname"='${this.schemaName}'` - ); + const { rows: views } = await this._client.raw(`SELECT * FROM "pg_views" WHERE "schemaname"='${this.schemaName}'`); let sqlString = ''; for (const view of views) { @@ -320,83 +318,24 @@ SET row_security = off;\n\n\n`; async getTriggers () { const { rows: triggers } = await this._client.raw( - `SHOW TRIGGERS FROM \`${this.schemaName}\`` + `SELECT * FROM "information_schema"."triggers" WHERE "trigger_schema"='${this.schemaName}'` ); - const generatedTables = this._tables - .filter(t => t.includeStructure) - .map(t => t.table); let sqlString = ''; - - for (const trigger of triggers) { - const { - Trigger: name, - Timing: timing, - Event: event, - Table: table, - Statement: statement, - sql_mode: sqlMode - } = trigger; - - if (!generatedTables.includes(table)) continue; - - const definer = this.getEscapedDefiner(trigger.Definer); - sqlString += '/*!50003 SET @OLD_SQL_MODE=@@SQL_MODE*/;;\n'; - sqlString += `/*!50003 SET SQL_MODE="${sqlMode}" */;\n`; - sqlString += 'DELIMITER ;;\n'; - sqlString += '/*!50003 CREATE*/ '; - sqlString += `/*!50017 DEFINER=${definer}*/ `; - sqlString += `/*!50003 TRIGGER \`${name}\` ${timing} ${event} ON \`${table}\` FOR EACH ROW ${statement}*/;;\n`; - sqlString += 'DELIMITER ;\n'; - sqlString += '/*!50003 SET SQL_MODE=@OLD_SQL_MODE */;\n\n'; - } - - return sqlString; - } - - async getSchedulers () { - const { rows: schedulers } = await this._client.raw( - `SELECT *, EVENT_SCHEMA AS \`Db\`, EVENT_NAME AS \`Name\` FROM information_schema.\`EVENTS\` WHERE EVENT_SCHEMA = '${this.schemaName}'` - ); - let sqlString = ''; - - for (const scheduler of schedulers) { - const { - EVENT_NAME: name, - SQL_MODE: sqlMode, - EVENT_TYPE: type, - INTERVAL_VALUE: intervalValue, - INTERVAL_FIELD: intervalField, - STARTS: starts, - ENDS: ends, - EXECUTE_AT: at, - ON_COMPLETION: onCompletion, - STATUS: status, - EVENT_DEFINITION: definition - } = scheduler; - - const definer = this.getEscapedDefiner(scheduler.DEFINER); - const comment = this.escapeAndQuote(scheduler.EVENT_COMMENT); - - sqlString += `/*!50106 DROP EVENT IF EXISTS \`${name}\` */;\n`; - sqlString += '/*!50003 SET @OLD_SQL_MODE=@@SQL_MODE*/;;\n'; - sqlString += `/*!50003 SET SQL_MODE='${sqlMode}' */;\n`; - sqlString += 'DELIMITER ;;\n'; - sqlString += '/*!50106 CREATE*/ '; - sqlString += `/*!50117 DEFINER=${definer}*/ `; - sqlString += `/*!50106 EVENT \`${name}\` ON SCHEDULE `; - if (type === 'RECURRING') { - sqlString += `EVERY ${intervalValue} ${intervalField} STARTS '${starts}' `; - - if (ends) sqlString += `ENDS '${ends}' `; + const remappedTriggers = triggers.reduce((acc, trigger) => { + const i = acc.findIndex(t => t.trigger_name === trigger.trigger_name && t.event_object_table === trigger.event_object_table); + if (i === -1) { + trigger.events = [trigger.event_manipulation]; + acc.push(trigger); } - else sqlString += `AT '${at}' `; - sqlString += `ON COMPLETION ${onCompletion} ${ - status === 'disabled' ? 'DISABLE' : 'ENABLE' - } COMMENT ${comment || '\'\''} DO ${definition}*/;;\n`; - sqlString += 'DELIMITER ;\n'; - sqlString += '/*!50003 SET SQL_MODE=@OLD_SQL_MODE*/;;\n'; - } + else + acc[i].events.push(trigger.event_manipulation); + + return acc; + }, []); + + for (const trigger of remappedTriggers) + sqlString += `\nCREATE TRIGGER "${trigger.trigger_name}" ${trigger.action_timing} ${trigger.events.join(' OR ')} ON "${trigger.event_object_table}" FOR EACH ${trigger.action_orientation} ${trigger.action_statement};\n`; return sqlString; } From a8ca8f2f76ab36c4afe84d602709386315f4b7d1 Mon Sep 17 00:00:00 2001 From: Fabio Di Stasio Date: Wed, 23 Mar 2022 13:26:46 +0100 Subject: [PATCH 5/9] feat(PostgreSQL): export functions and procedures --- .../libs/exporters/sql/PostgreSQLExporter.js | 83 +++++++------------ src/renderer/components/ModalExportSchema.vue | 6 +- 2 files changed, 30 insertions(+), 59 deletions(-) diff --git a/src/main/libs/exporters/sql/PostgreSQLExporter.js b/src/main/libs/exporters/sql/PostgreSQLExporter.js index cff70531..63ebe138 100644 --- a/src/main/libs/exporters/sql/PostgreSQLExporter.js +++ b/src/main/libs/exporters/sql/PostgreSQLExporter.js @@ -23,7 +23,7 @@ SET xmloption = content; SET client_min_messages = warning; SET row_security = off;\n\n\n`; - dump += await this.getTypes(); + dump += await this.getCreateTypes(); return dump; } @@ -162,7 +162,7 @@ SET row_security = off;\n\n\n`; let rowCount = 0; const sqlStr = ''; - const countResults = await this._client.raw(`SELECT COUNT(1) as count FROM "${tableName}"`); + const countResults = await this._client.raw(`SELECT COUNT(1) as count FROM "${this.schemaName}"."${tableName}"`); if (countResults.rows.length === 1) rowCount = countResults.rows[0].count; if (rowCount > 0) { @@ -180,7 +180,7 @@ SET row_security = off;\n\n\n`; yield sqlStr; const stream = await this._queryStream( - `SELECT ${columnNames} FROM "${tableName}"` + `SELECT ${columnNames} FROM "${this.schemaName}"."${tableName}"` ); for await (const row of stream) { @@ -270,7 +270,7 @@ SET row_security = off;\n\n\n`; } } - async getTypes () { + async getCreateTypes () { let sqlString = ''; const { rows: types } = await this._client.raw(` SELECT pg_type.typname, pg_enum.enumlabel @@ -337,80 +337,53 @@ SET row_security = off;\n\n\n`; for (const trigger of remappedTriggers) sqlString += `\nCREATE TRIGGER "${trigger.trigger_name}" ${trigger.action_timing} ${trigger.events.join(' OR ')} ON "${trigger.event_object_table}" FOR EACH ${trigger.action_orientation} ${trigger.action_statement};\n`; + // Trigger functions + const { rows: triggerFunctions } = await this._client.raw( + `SELECT DISTINCT routine_name AS name FROM information_schema.routines WHERE routine_type = 'FUNCTION' AND routine_schema = '${this.schemaName}' AND data_type = 'trigger'` + ); + + for (const func of triggerFunctions) { + const { rows: functionDef } = await this._client.raw( + `SELECT pg_get_functiondef((SELECT oid FROM pg_proc WHERE proname = '${func.name}')) AS definition` + ); + sqlString += `\n${functionDef[0].definition};\n`; + } + return sqlString; } async getFunctions () { + let sqlString = ''; const { rows: functions } = await this._client.raw( - `SHOW FUNCTION STATUS WHERE \`Db\` = '${this.schemaName}';` + `SELECT DISTINCT routine_name AS name FROM information_schema.routines WHERE routine_type = 'FUNCTION' AND routine_schema = '${this.schemaName}' AND data_type != 'trigger'` ); - let sqlString = ''; - for (const func of functions) { - const definer = this.getEscapedDefiner(func.Definer); - sqlString += await this.getRoutineSyntax( - func.Name, - func.Type, - definer + const { rows: functionDef } = await this._client.raw( + `SELECT pg_get_functiondef((SELECT oid FROM pg_proc WHERE proname = '${func.name}')) AS definition` ); + sqlString += `\n${functionDef[0].definition};\n`; } return sqlString; } async getRoutines () { - const { rows: routines } = await this._client.raw( - `SHOW PROCEDURE STATUS WHERE \`Db\` = '${this.schemaName}';` + let sqlString = ''; + const { rows: functions } = await this._client.raw( + `SELECT DISTINCT routine_name AS name FROM information_schema.routines WHERE routine_type = 'PROCEDURE' AND routine_schema = '${this.schemaName}'` ); - let sqlString = ''; - - for (const routine of routines) { - const definer = this.getEscapedDefiner(routine.Definer); - - sqlString += await this.getRoutineSyntax( - routine.Name, - routine.Type, - definer + for (const func of functions) { + const { rows: functionDef } = await this._client.raw( + `SELECT pg_get_functiondef((SELECT oid FROM pg_proc WHERE proname = '${func.name}')) AS definition` ); + sqlString += `\n${functionDef[0].definition};\n`; } return sqlString; } - async getRoutineSyntax (name, type, definer) { - const { rows: routines } = await this._client.raw( - `SHOW CREATE ${type} \`${this.schemaName}\`.\`${name}\`` - ); - - if (routines.length === 0) return ''; - - const routine = routines[0]; - - const fieldName = `Create ${type === 'PROCEDURE' ? 'Procedure' : 'Function'}`; - const sqlMode = routine.sql_mode; - const createProcedure = routine[fieldName]; - let sqlString = ''; - - if (createProcedure) { // If procedure body not empty - const startOffset = createProcedure.indexOf(type); - const procedureBody = createProcedure.substring(startOffset); - - sqlString += `/*!50003 DROP ${type} IF EXISTS ${name}*/;;\n`; - sqlString += '/*!50003 SET @OLD_SQL_MODE=@@SQL_MODE*/;;\n'; - sqlString += `/*!50003 SET SQL_MODE="${sqlMode}"*/;;\n`; - sqlString += 'DELIMITER ;;\n'; - sqlString += `/*!50003 CREATE*/ /*!50020 DEFINER=${definer}*/ /*!50003 ${procedureBody}*/;;\n`; - sqlString += 'DELIMITER ;\n'; - sqlString += '/*!50003 SET SQL_MODE=@OLD_SQL_MODE*/;\n'; - } - - return sqlString; - } - - async getCreateType () {} - async _queryStream (sql) { if (process.env.NODE_ENV === 'development') console.log('EXPORTER:', sql); const connection = await this._client.getConnection(); diff --git a/src/renderer/components/ModalExportSchema.vue b/src/renderer/components/ModalExportSchema.vue index 4715ab53..52d5b5b5 100644 --- a/src/renderer/components/ModalExportSchema.vue +++ b/src/renderer/components/ModalExportSchema.vue @@ -349,14 +349,12 @@ export default { includeDropStatement: true })); - const structure = ['views', 'triggers', 'routines', 'functions', 'schedulers', 'triggerFunctions']; + const structure = ['views', 'triggers', 'routines', 'functions', 'schedulers']; structure.forEach(feat => { const val = customizations[this.currentWorkspace.client][feat]; - if (val) { - if (feat === 'triggerFunctions') feat = 'triggerFunction';// TODO: remove after l18n refactor + if (val) this.$set(this.options.includes, feat, true); - } }); ipcRenderer.on('export-progress', this.updateProgress); From 408ddeda5634ab6bf41eff760271669170b60eb6 Mon Sep 17 00:00:00 2001 From: Fabio Di Stasio Date: Sun, 27 Mar 2022 11:41:35 +0200 Subject: [PATCH 6/9] perf(PostgreSQL): improved dump file --- .../libs/exporters/sql/PostgreSQLExporter.js | 83 ++++++++++++++----- src/main/libs/exporters/sql/SqlExporter.js | 9 +- src/renderer/components/ModalExportSchema.vue | 2 +- 3 files changed, 73 insertions(+), 21 deletions(-) diff --git a/src/main/libs/exporters/sql/PostgreSQLExporter.js b/src/main/libs/exporters/sql/PostgreSQLExporter.js index 63ebe138..b6a3ee88 100644 --- a/src/main/libs/exporters/sql/PostgreSQLExporter.js +++ b/src/main/libs/exporters/sql/PostgreSQLExporter.js @@ -119,7 +119,7 @@ SET row_security = off;\n\n\n`; .run(); for (const index of indexes) - createSql += `${index.indexdef};\n`; + createSql += `${index.indexdef.replaceAll(`${this.schemaName}.`, '')};\n`; // Table foreigns const { rows: foreigns } = await this._client.raw(` @@ -147,8 +147,8 @@ SET row_security = off;\n\n\n`; `); for (const foreign of foreigns) { - createSql += `\nALTER TABLE ONLY "${tableName}" - ADD CONSTRAINT "${foreign.constraint_name}" FOREIGN KEY ("${foreign.column_name}") REFERENCES "${foreign.table_schema}"."${foreign.table_name}" ("${foreign.foreign_column_name}") ON UPDATE ${foreign.update_rule} ON DELETE ${foreign.delete_rule};\n`; + this._postTablesSql += `\nALTER TABLE ONLY "${tableName}" + ADD CONSTRAINT "${foreign.constraint_name}" FOREIGN KEY ("${foreign.column_name}") REFERENCES "${foreign.foreign_table_name}" ("${foreign.foreign_column_name}") ON UPDATE ${foreign.update_rule} ON DELETE ${foreign.delete_rule};\n`; } return createSql; @@ -304,12 +304,54 @@ SET row_security = off;\n\n\n`; return sqlString; } + async getCreateAggregates () { + let sqlString = ''; + + const { rows: aggregates } = await this._client.raw(` + SELECT proname + FROM pg_proc + WHERE prokind = 'a' + AND pronamespace::regnamespace::text = '${this.schemaName}' + ORDER BY 1; + `); + + if (aggregates.length) { + for (const aggregate of aggregates) { + const { rows: aggregateDef } = await this._client.raw( + `SELECT + format( + E'CREATE AGGREGATE %s (\n%s\n);' + , (pg_identify_object('pg_proc'::regclass, aggfnoid, 0)).identity + , array_to_string( + ARRAY[ + format(E'\tSFUNC = %s', aggtransfn::regproc) + , format(E'\tSTYPE = %s', format_type(aggtranstype, NULL)) + , CASE aggfinalfn WHEN '-'::regproc THEN NULL ELSE format(E'\tFINALFUNC = %s',aggfinalfn::text) END + , CASE aggsortop WHEN 0 THEN NULL ELSE format(E'\tSORTOP = %s', oprname) END + , CASE WHEN agginitval IS NULL THEN NULL ELSE format(E'\tINITCOND = %s', agginitval) END + ] + , E',\n' + ) + ) + FROM pg_aggregate + LEFT JOIN pg_operator ON pg_operator.oid = aggsortop + WHERE aggfnoid = '${this.schemaName}.${aggregate.proname}'::regproc;` + ); + + if (aggregateDef.length) + sqlString += '\n\n' + aggregateDef[0].format.replaceAll(`${this.schemaName}.`, ''); + } + } + + return sqlString + '\n\n\n'; + } + async getViews () { const { rows: views } = await this._client.raw(`SELECT * FROM "pg_views" WHERE "schemaname"='${this.schemaName}'`); let sqlString = ''; for (const view of views) { - sqlString += `\nDROP VIEW IF EXISTS '${view.viewname}';\n`; + sqlString += `\nDROP VIEW IF EXISTS "${view.viewname}";\n`; sqlString += `\nCREATE VIEW "${view.viewname}" AS \n${view.definition}\n`; } @@ -317,11 +359,24 @@ SET row_security = off;\n\n\n`; } async getTriggers () { + let sqlString = ''; + + // Trigger functions + const { rows: triggerFunctions } = await this._client.raw( + `SELECT DISTINCT routine_name AS name FROM information_schema.routines WHERE routine_type = 'FUNCTION' AND routine_schema = '${this.schemaName}' AND data_type = 'trigger'` + ); + + for (const func of triggerFunctions) { + const { rows: functionDef } = await this._client.raw( + `SELECT pg_get_functiondef((SELECT oid FROM pg_proc WHERE proname = '${func.name}')) AS definition` + ); + sqlString += `\n${functionDef[0].definition.replaceAll(`${this.schemaName}.`, '')};\n`; + } + const { rows: triggers } = await this._client.raw( `SELECT * FROM "information_schema"."triggers" WHERE "trigger_schema"='${this.schemaName}'` ); - let sqlString = ''; const remappedTriggers = triggers.reduce((acc, trigger) => { const i = acc.findIndex(t => t.trigger_name === trigger.trigger_name && t.event_object_table === trigger.event_object_table); if (i === -1) { @@ -337,18 +392,6 @@ SET row_security = off;\n\n\n`; for (const trigger of remappedTriggers) sqlString += `\nCREATE TRIGGER "${trigger.trigger_name}" ${trigger.action_timing} ${trigger.events.join(' OR ')} ON "${trigger.event_object_table}" FOR EACH ${trigger.action_orientation} ${trigger.action_statement};\n`; - // Trigger functions - const { rows: triggerFunctions } = await this._client.raw( - `SELECT DISTINCT routine_name AS name FROM information_schema.routines WHERE routine_type = 'FUNCTION' AND routine_schema = '${this.schemaName}' AND data_type = 'trigger'` - ); - - for (const func of triggerFunctions) { - const { rows: functionDef } = await this._client.raw( - `SELECT pg_get_functiondef((SELECT oid FROM pg_proc WHERE proname = '${func.name}')) AS definition` - ); - sqlString += `\n${functionDef[0].definition};\n`; - } - return sqlString; } @@ -362,9 +405,11 @@ SET row_security = off;\n\n\n`; const { rows: functionDef } = await this._client.raw( `SELECT pg_get_functiondef((SELECT oid FROM pg_proc WHERE proname = '${func.name}')) AS definition` ); - sqlString += `\n${functionDef[0].definition};\n`; + sqlString += `\n${functionDef[0].definition.replaceAll(`${this.schemaName}.`, '')};\n`; } + sqlString += await this.getCreateAggregates(); + return sqlString; } @@ -378,7 +423,7 @@ SET row_security = off;\n\n\n`; const { rows: functionDef } = await this._client.raw( `SELECT pg_get_functiondef((SELECT oid FROM pg_proc WHERE proname = '${func.name}')) AS definition` ); - sqlString += `\n${functionDef[0].definition};\n`; + sqlString += `\n${functionDef[0].definition.replaceAll(`${this.schemaName}.`, '')};\n`; } return sqlString; diff --git a/src/main/libs/exporters/sql/SqlExporter.js b/src/main/libs/exporters/sql/SqlExporter.js index 21164201..f5e20c88 100644 --- a/src/main/libs/exporters/sql/SqlExporter.js +++ b/src/main/libs/exporters/sql/SqlExporter.js @@ -5,7 +5,8 @@ export class SqlExporter extends BaseExporter { constructor (client, tables, options) { super(tables, options); this._client = client; - this._commentChar = '#'; + this._commentChar = '--'; + this._postTablesSql = ''; } get schemaName () { @@ -90,6 +91,12 @@ export class SqlExporter extends BaseExporter { this.writeString('\n\n'); } + // SQL to execute after tables creation + if (this._postTablesSql) { + this.writeString(this._postTablesSql); + this.writeString('\n\n'); + } + for (const item of extraItems) { const processingMethod = `get${item.charAt(0).toUpperCase() + item.slice(1)}`; exportState.currentItemIndex++; diff --git a/src/renderer/components/ModalExportSchema.vue b/src/renderer/components/ModalExportSchema.vue index 52d5b5b5..7ab9e916 100644 --- a/src/renderer/components/ModalExportSchema.vue +++ b/src/renderer/components/ModalExportSchema.vue @@ -349,7 +349,7 @@ export default { includeDropStatement: true })); - const structure = ['views', 'triggers', 'routines', 'functions', 'schedulers']; + const structure = ['functions', 'views', 'triggers', 'routines', 'schedulers']; structure.forEach(feat => { const val = customizations[this.currentWorkspace.client][feat]; From 638a88a1fb35c048ff4c6d120aaaef831c846f58 Mon Sep 17 00:00:00 2001 From: Fabio Di Stasio Date: Fri, 1 Apr 2022 18:36:02 +0200 Subject: [PATCH 7/9] perf(PostgreSQL): improved views exportation --- .../libs/exporters/sql/PostgreSQLExporter.js | 21 ++++++++++++++++++- 1 file changed, 20 insertions(+), 1 deletion(-) diff --git a/src/main/libs/exporters/sql/PostgreSQLExporter.js b/src/main/libs/exporters/sql/PostgreSQLExporter.js index b6a3ee88..5c9a811f 100644 --- a/src/main/libs/exporters/sql/PostgreSQLExporter.js +++ b/src/main/libs/exporters/sql/PostgreSQLExporter.js @@ -352,7 +352,26 @@ SET row_security = off;\n\n\n`; for (const view of views) { sqlString += `\nDROP VIEW IF EXISTS "${view.viewname}";\n`; - sqlString += `\nCREATE VIEW "${view.viewname}" AS \n${view.definition}\n`; + + const { rows: columns } = await this._client + .select('*') + .schema('information_schema') + .from('columns') + .where({ table_schema: `= '${this.schemaName}'`, table_name: `= '${view.viewname}'` }) + .orderBy({ ordinal_position: 'ASC' }) + .run(); + + sqlString += ` +CREATE VIEW "${view.viewname}" AS +SELECT + ${columns.reduce((acc, curr) => { + const fieldType = curr.data_type === 'USER-DEFINED' ? curr.udt_name : curr.data_type; + acc.push(`NULL::${fieldType}${curr.character_maximum_length ? `(${curr.character_maximum_length})` : ''} AS "${curr.column_name}"`); + return acc; + }, []).join(',\n ')}; +`; + + sqlString += `\nCREATE OR REPLACE VIEW "${view.viewname}" AS \n${view.definition}\n`; } return sqlString; From 0f9c991f539560913fa0e9361a16e6448a066a27 Mon Sep 17 00:00:00 2001 From: Fabio Di Stasio Date: Sat, 2 Apr 2022 11:44:55 +0200 Subject: [PATCH 8/9] fix(PostgreSQL): wrong values exporting table content --- src/common/customizations/defaults.js | 1 + src/common/customizations/mysql.js | 1 + .../libs/exporters/sql/PostgreSQLExporter.js | 140 ++++++++---------- src/renderer/components/ModalExportSchema.vue | 46 +++--- 4 files changed, 88 insertions(+), 100 deletions(-) diff --git a/src/common/customizations/defaults.js b/src/common/customizations/defaults.js index 423c31ae..40b949e2 100644 --- a/src/common/customizations/defaults.js +++ b/src/common/customizations/defaults.js @@ -39,6 +39,7 @@ module.exports = { schemaEdit: false, schemaDrop: false, schemaExport: false, + exportByChunks: false, schemaImport: false, tableSettings: false, tableOptions: false, diff --git a/src/common/customizations/mysql.js b/src/common/customizations/mysql.js index 075c498c..5d47cac9 100644 --- a/src/common/customizations/mysql.js +++ b/src/common/customizations/mysql.js @@ -35,6 +35,7 @@ module.exports = { schemaEdit: true, schemaDrop: true, schemaExport: true, + exportByChunks: true, schemaImport: true, tableSettings: true, viewSettings: true, diff --git a/src/main/libs/exporters/sql/PostgreSQLExporter.js b/src/main/libs/exporters/sql/PostgreSQLExporter.js index 5c9a811f..c4815ad9 100644 --- a/src/main/libs/exporters/sql/PostgreSQLExporter.js +++ b/src/main/libs/exporters/sql/PostgreSQLExporter.js @@ -1,5 +1,5 @@ import { SqlExporter } from './SqlExporter'; -import { BLOB, BIT, DATE, DATETIME, FLOAT, SPATIAL, IS_MULTI_SPATIAL, NUMBER } from 'common/fieldTypes'; +import { BLOB, BIT, DATE, DATETIME, FLOAT, NUMBER, TEXT_SEARCH } from 'common/fieldTypes'; import hexToBinary from 'common/libs/hexToBinary'; import { getArrayDepth } from 'common/libs/getArrayDepth'; import moment from 'moment'; @@ -17,12 +17,14 @@ SET lock_timeout = 0; SET idle_in_transaction_session_timeout = 0; SET client_encoding = 'UTF8'; SET standard_conforming_strings = on; --- SELECT pg_catalog.set_config('search_path', '', false); +SELECT pg_catalog.set_config('search_path', '', false); SET check_function_bodies = false; SET xmloption = content; SET client_min_messages = warning; SET row_security = off;\n\n\n`; + if (this.schemaName !== 'public') dump += `CREATE SCHEMA "${this.schemaName}";\n\n`; + dump += await this.getCreateTypes(); return dump; @@ -43,19 +45,19 @@ SET row_security = off;\n\n\n`; }; // Table columns - const { rows } = await this._client - .select('*') - .schema('information_schema') - .from('columns') - .where({ table_schema: `= '${this.schemaName}'`, table_name: `= '${tableName}'` }) - .orderBy({ ordinal_position: 'ASC' }) - .run(); + const { rows } = await this._client.raw(` + SELECT * + FROM "information_schema"."columns" + WHERE "table_schema" = '${this.schemaName}' + AND "table_name" = '${tableName}' + ORDER BY "ordinal_position" ASC + `, { schema: 'information_schema' }); if (!rows.length) return ''; for (const column of rows) { let fieldType = column.data_type; - if (fieldType === 'USER-DEFINED') fieldType = column.udt_name; + if (fieldType === 'USER-DEFINED') fieldType = `"${this.schemaName}".${column.udt_name}`; else if (fieldType === 'ARRAY') { if (Object.keys(arrayTypes).includes(fieldType)) fieldType = arrayTypes[type] + '[]'; @@ -71,8 +73,7 @@ SET row_security = off;\n\n\n`; if (column.column_default) { columnArr.push(`DEFAULT ${column.column_default}`); if (column.column_default.includes('nextval')) { - let sequenceName = column.column_default.split('\'')[1]; - if (sequenceName.includes('.')) sequenceName = sequenceName.split('.')[1]; + const sequenceName = column.column_default.split('\'')[1]; sequences.push(sequenceName); } } @@ -82,7 +83,9 @@ SET row_security = off;\n\n\n`; } // Table sequences - for (const sequence of sequences) { + for (let sequence of sequences) { + if (sequence.includes('.')) sequence = sequence.split('.')[1]; + const { rows } = await this._client .select('*') .schema('information_schema') @@ -91,7 +94,7 @@ SET row_security = off;\n\n\n`; .run(); if (rows.length) { - createSql += `CREATE SEQUENCE "${sequence}" + createSql += `CREATE SEQUENCE "${this.schemaName}"."${sequence}" START WITH ${rows[0].start_value} INCREMENT BY ${rows[0].increment} MINVALUE ${rows[0].minimum_value} @@ -103,7 +106,7 @@ SET row_security = off;\n\n\n`; } // Table create - createSql += `\nCREATE TABLE "${tableName}"( + createSql += `\nCREATE TABLE "${this.schemaName}"."${tableName}"( ${columnsSql.join(',\n ')} );\n`; @@ -119,7 +122,7 @@ SET row_security = off;\n\n\n`; .run(); for (const index of indexes) - createSql += `${index.indexdef.replaceAll(`${this.schemaName}.`, '')};\n`; + createSql += `${index.indexdef};\n`; // Table foreigns const { rows: foreigns } = await this._client.raw(` @@ -147,15 +150,15 @@ SET row_security = off;\n\n\n`; `); for (const foreign of foreigns) { - this._postTablesSql += `\nALTER TABLE ONLY "${tableName}" - ADD CONSTRAINT "${foreign.constraint_name}" FOREIGN KEY ("${foreign.column_name}") REFERENCES "${foreign.foreign_table_name}" ("${foreign.foreign_column_name}") ON UPDATE ${foreign.update_rule} ON DELETE ${foreign.delete_rule};\n`; + this._postTablesSql += `\nALTER TABLE ONLY "${this.schemaName}"."${tableName}" + ADD CONSTRAINT "${foreign.constraint_name}" FOREIGN KEY ("${foreign.column_name}") REFERENCES "${this.schemaName}"."${foreign.foreign_table_name}" ("${foreign.foreign_column_name}") ON UPDATE ${foreign.update_rule} ON DELETE ${foreign.delete_rule};\n`; } return createSql; } getDropTable (tableName) { - return `DROP TABLE IF EXISTS "${tableName}";`; + return `DROP TABLE IF EXISTS "${this.schemaName}"."${tableName}";`; } async * getTableInsert (tableName) { @@ -166,16 +169,12 @@ SET row_security = off;\n\n\n`; if (countResults.rows.length === 1) rowCount = countResults.rows[0].count; if (rowCount > 0) { - let queryLength = 0; - let rowsWritten = 0; - const { sqlInsertDivider, sqlInsertAfter } = this._options; const columns = await this._client.getTableColumns({ table: tableName, schema: this.schemaName }); - const notGeneratedColumns = columns.filter(col => !col.generated); - const columnNames = notGeneratedColumns.map(col => '"' + col.name + '"').join(', '); + const columnNames = columns.map(col => '"' + col.name + '"').join(', '); yield sqlStr; @@ -190,20 +189,12 @@ SET row_security = off;\n\n\n`; return; } - let sqlInsertString = `INSERT INTO "${tableName}" (${columnNames}) VALUES`; - - if ( - (sqlInsertDivider === 'bytes' && queryLength >= sqlInsertAfter * 1024) || - (sqlInsertDivider === 'rows' && rowsWritten === sqlInsertAfter) - ) { - queryLength = 0; - rowsWritten = 0; - } + let sqlInsertString = `INSERT INTO "${this.schemaName}"."${tableName}" (${columnNames}) VALUES`; sqlInsertString += ' ('; - for (const i in notGeneratedColumns) { - const column = notGeneratedColumns[i]; + for (const i in columns) { + const column = columns[i]; const val = row[column.name]; if (val === null) sqlInsertString += 'NULL'; @@ -221,31 +212,24 @@ SET row_security = off;\n\n\n`; ? this.escapeAndQuote(moment(val).format(`YYYY-MM-DD HH:mm:ss${datePrecision}`)) : this.escapeAndQuote(val); } + else if (column.isArray) { + let parsedVal; + if (Array.isArray(val)) + parsedVal = JSON.stringify(val).replaceAll('[', '{').replaceAll(']', '}'); + else + parsedVal = typeof val === 'string' ? val.replaceAll('[', '{').replaceAll(']', '}') : ''; + sqlInsertString += `'${parsedVal}'`; + } + else if (TEXT_SEARCH.includes(column.type)) + sqlInsertString += `'${val.replaceAll('\'', '\'\'')}'`; else if (BIT.includes(column.type)) sqlInsertString += `b'${hexToBinary(Buffer.from(val).toString('hex'))}'`; else if (BLOB.includes(column.type)) - sqlInsertString += `X'${val.toString('hex').toUpperCase()}'`; + sqlInsertString += `decode('${val.toString('hex').toUpperCase()}', 'hex')`; else if (NUMBER.includes(column.type)) sqlInsertString += val; else if (FLOAT.includes(column.type)) sqlInsertString += parseFloat(val); - else if (SPATIAL.includes(column.type)) { - let geoJson; - if (IS_MULTI_SPATIAL.includes(column.type)) { - const features = []; - for (const element of val) - features.push(this.getMarkers(element)); - - geoJson = { - type: 'FeatureCollection', - features - }; - } - else - geoJson = this._getGeoJSON(val); - - sqlInsertString += `ST_GeomFromGeoJSON('${JSON.stringify(geoJson)}')`; - } else if (val === '') sqlInsertString += '\'\''; else { sqlInsertString += typeof val === 'string' @@ -255,14 +239,12 @@ SET row_security = off;\n\n\n`; : val; } - if (parseInt(i) !== notGeneratedColumns.length - 1) + if (parseInt(i) !== columns.length - 1) sqlInsertString += ', '; } sqlInsertString += ');\n'; - queryLength += sqlInsertString.length; - rowsWritten++; yield sqlInsertString; } @@ -293,7 +275,7 @@ SET row_security = off;\n\n\n`; }, []); for (const type of typesArr) { - sqlString += `CREATE TYPE "${type.name}" AS ENUM ( + sqlString += `CREATE TYPE "${this.schemaName}"."${type.name}" AS ENUM ( ${type.enums.join(',\n\t')} );`; } @@ -339,7 +321,7 @@ SET row_security = off;\n\n\n`; ); if (aggregateDef.length) - sqlString += '\n\n' + aggregateDef[0].format.replaceAll(`${this.schemaName}.`, ''); + sqlString += '\n\n' + aggregateDef[0].format; } } @@ -353,25 +335,25 @@ SET row_security = off;\n\n\n`; for (const view of views) { sqlString += `\nDROP VIEW IF EXISTS "${view.viewname}";\n`; - const { rows: columns } = await this._client - .select('*') - .schema('information_schema') - .from('columns') - .where({ table_schema: `= '${this.schemaName}'`, table_name: `= '${view.viewname}'` }) - .orderBy({ ordinal_position: 'ASC' }) - .run(); + // const { rows: columns } = await this._client + // .select('*') + // .schema('information_schema') + // .from('columns') + // .where({ table_schema: `= '${this.schemaName}'`, table_name: `= '${view.viewname}'` }) + // .orderBy({ ordinal_position: 'ASC' }) + // .run(); - sqlString += ` -CREATE VIEW "${view.viewname}" AS -SELECT - ${columns.reduce((acc, curr) => { - const fieldType = curr.data_type === 'USER-DEFINED' ? curr.udt_name : curr.data_type; - acc.push(`NULL::${fieldType}${curr.character_maximum_length ? `(${curr.character_maximum_length})` : ''} AS "${curr.column_name}"`); - return acc; - }, []).join(',\n ')}; -`; + // sqlString += ` + // CREATE VIEW "${this.schemaName}"."${view.viewname}" AS + // SELECT + // ${columns.reduce((acc, curr) => { + // const fieldType = curr.data_type === 'USER-DEFINED' ? curr.udt_name : curr.data_type; + // acc.push(`NULL::${fieldType}${curr.character_maximum_length ? `(${curr.character_maximum_length})` : ''} AS "${curr.column_name}"`); + // return acc; + // }, []).join(',\n ')}; + // `; - sqlString += `\nCREATE OR REPLACE VIEW "${view.viewname}" AS \n${view.definition}\n`; + sqlString += `\nCREATE OR REPLACE VIEW "${this.schemaName}"."${view.viewname}" AS \n${view.definition}\n`; } return sqlString; @@ -389,7 +371,7 @@ SELECT const { rows: functionDef } = await this._client.raw( `SELECT pg_get_functiondef((SELECT oid FROM pg_proc WHERE proname = '${func.name}')) AS definition` ); - sqlString += `\n${functionDef[0].definition.replaceAll(`${this.schemaName}.`, '')};\n`; + sqlString += `\n${functionDef[0].definition};\n`; } const { rows: triggers } = await this._client.raw( @@ -409,7 +391,7 @@ SELECT }, []); for (const trigger of remappedTriggers) - sqlString += `\nCREATE TRIGGER "${trigger.trigger_name}" ${trigger.action_timing} ${trigger.events.join(' OR ')} ON "${trigger.event_object_table}" FOR EACH ${trigger.action_orientation} ${trigger.action_statement};\n`; + sqlString += `\nCREATE TRIGGER "${trigger.trigger_name}" ${trigger.action_timing} ${trigger.events.join(' OR ')} ON "${this.schemaName}"."${trigger.event_object_table}" FOR EACH ${trigger.action_orientation} ${trigger.action_statement};\n`; return sqlString; } @@ -424,7 +406,7 @@ SELECT const { rows: functionDef } = await this._client.raw( `SELECT pg_get_functiondef((SELECT oid FROM pg_proc WHERE proname = '${func.name}')) AS definition` ); - sqlString += `\n${functionDef[0].definition.replaceAll(`${this.schemaName}.`, '')};\n`; + sqlString += `\n${functionDef[0].definition};\n`; } sqlString += await this.getCreateAggregates(); @@ -442,7 +424,7 @@ SELECT const { rows: functionDef } = await this._client.raw( `SELECT pg_get_functiondef((SELECT oid FROM pg_proc WHERE proname = '${func.name}')) AS definition` ); - sqlString += `\n${functionDef[0].definition.replaceAll(`${this.schemaName}.`, '')};\n`; + sqlString += `\n${functionDef[0].definition};\n`; } return sqlString; diff --git a/src/renderer/components/ModalExportSchema.vue b/src/renderer/components/ModalExportSchema.vue index 7ab9e916..5f719c0d 100644 --- a/src/renderer/components/ModalExportSchema.vue +++ b/src/renderer/components/ModalExportSchema.vue @@ -192,28 +192,29 @@ > {{ $tc(`word.${key}`, 2) }} - -
- {{ $t('message.newInserStmtEvery') }}: -
-
-
- +
+
+ {{ $t('message.newInserStmtEvery') }}:
-
- +
+
+ +
+
+ +
@@ -306,6 +307,9 @@ export default { currentWorkspace () { return this.getWorkspace(this.selectedWorkspace); }, + customizations () { + return this.currentWorkspace.customizations; + }, schemaItems () { const db = this.currentWorkspace.structure.find(db => db.name === this.selectedSchema); if (db) From 6086ca4a80b9ad6a07086446253d781f052d3abc Mon Sep 17 00:00:00 2001 From: Fabio Di Stasio Date: Thu, 7 Apr 2022 12:49:34 +0200 Subject: [PATCH 9/9] feat(PostgreSQL): sql dump importer --- src/main/libs/exporters/sql/MysqlExporter.js | 6 + src/main/libs/importers/sql/MysqlImporter.js | 11 +- .../libs/importers/sql/PostgreSQLImporter.js | 80 ++++++++++ .../libs/parsers/MySQLParser.js} | 2 +- src/main/libs/parsers/PostgreSQLParser.js | 142 ++++++++++++++++++ src/main/workers/importer.js | 8 +- 6 files changed, 238 insertions(+), 11 deletions(-) create mode 100644 src/main/libs/importers/sql/PostgreSQLImporter.js rename src/{common/libs/sqlParser.js => main/libs/parsers/MySQLParser.js} (97%) create mode 100644 src/main/libs/parsers/PostgreSQLParser.js diff --git a/src/main/libs/exporters/sql/MysqlExporter.js b/src/main/libs/exporters/sql/MysqlExporter.js index f571ae4d..c5460ba4 100644 --- a/src/main/libs/exporters/sql/MysqlExporter.js +++ b/src/main/libs/exporters/sql/MysqlExporter.js @@ -6,6 +6,12 @@ import moment from 'moment'; import { lineString, point, polygon } from '@turf/helpers'; export default class MysqlExporter extends SqlExporter { + constructor (...args) { + super(...args); + + this._commentChar = '#'; + } + async getSqlHeader () { let dump = await super.getSqlHeader(); dump += ` diff --git a/src/main/libs/importers/sql/MysqlImporter.js b/src/main/libs/importers/sql/MysqlImporter.js index 05c39941..dc9349da 100644 --- a/src/main/libs/importers/sql/MysqlImporter.js +++ b/src/main/libs/importers/sql/MysqlImporter.js @@ -1,8 +1,8 @@ import fs from 'fs/promises'; -import SqlParser from '../../../../common/libs/sqlParser'; +import MySQLParser from '../../parsers/MySQLParser'; import { BaseImporter } from '../BaseImporter'; -export default class MysqlImporter extends BaseImporter { +export default class MySQLImporter extends BaseImporter { constructor (client, options) { super(options); this._client = client; @@ -11,7 +11,7 @@ export default class MysqlImporter extends BaseImporter { async import () { try { const { size: totalFileSize } = await fs.stat(this._options.file); - const parser = new SqlParser(); + const parser = new MySQLParser(); let readPosition = 0; let queryCount = 0; @@ -22,11 +22,6 @@ export default class MysqlImporter extends BaseImporter { queryCount: 0 }); - // 1. detect file encoding - // 2. set fh encoding - // 3. detect sql mode - // 4. restore sql mode in case of exception - return new Promise((resolve, reject) => { this._fileHandler.pipe(parser); diff --git a/src/main/libs/importers/sql/PostgreSQLImporter.js b/src/main/libs/importers/sql/PostgreSQLImporter.js new file mode 100644 index 00000000..a18f22c9 --- /dev/null +++ b/src/main/libs/importers/sql/PostgreSQLImporter.js @@ -0,0 +1,80 @@ +import fs from 'fs/promises'; +import PostgreSQLParser from '../../parsers/PostgreSQLParser'; +import { BaseImporter } from '../BaseImporter'; + +export default class PostgreSQLImporter extends BaseImporter { + constructor (client, options) { + super(options); + this._client = client; + } + + async import () { + try { + const { size: totalFileSize } = await fs.stat(this._options.file); + const parser = new PostgreSQLParser(); + let readPosition = 0; + let queryCount = 0; + + this.emitUpdate({ + fileSize: totalFileSize, + readPosition: 0, + percentage: 0, + queryCount: 0 + }); + + return new Promise((resolve, reject) => { + this._fileHandler.pipe(parser); + + parser.on('error', reject); + + parser.on('close', async () => { + console.log('TOTAL QUERIES', queryCount); + console.log('import end'); + resolve(); + }); + + parser.on('data', async (query) => { + queryCount++; + parser.pause(); + + try { + await this._client.query(query); + } + catch (error) { + this.emit('query-error', { + sql: query, + message: error.hint || error.toString(), + sqlSnippet: error.sql, + time: new Date().getTime() + }); + } + + this.emitUpdate({ + queryCount, + readPosition, + percentage: readPosition / totalFileSize * 100 + }); + this._fileHandler.pipe(parser); + parser.resume(); + }); + + parser.on('pause', () => { + this._fileHandler.unpipe(parser); + this._fileHandler.readableFlowing = false; + }); + + this._fileHandler.on('data', (chunk) => { + readPosition += chunk.length; + }); + + this._fileHandler.on('error', (err) => { + console.log(err); + reject(err); + }); + }); + } + catch (err) { + console.log(err); + } + } +} diff --git a/src/common/libs/sqlParser.js b/src/main/libs/parsers/MySQLParser.js similarity index 97% rename from src/common/libs/sqlParser.js rename to src/main/libs/parsers/MySQLParser.js index 933277b5..3157a5e3 100644 --- a/src/common/libs/sqlParser.js +++ b/src/main/libs/parsers/MySQLParser.js @@ -1,6 +1,6 @@ import { Transform } from 'stream'; -export default class SqlParser extends Transform { +export default class MySQLParser extends Transform { constructor (opts) { opts = { delimiter: ';', diff --git a/src/main/libs/parsers/PostgreSQLParser.js b/src/main/libs/parsers/PostgreSQLParser.js new file mode 100644 index 00000000..883a07ac --- /dev/null +++ b/src/main/libs/parsers/PostgreSQLParser.js @@ -0,0 +1,142 @@ +import { Transform } from 'stream'; + +export default class PostgreSQLParser extends Transform { + constructor (opts) { + opts = { + delimiter: ';', + encoding: 'utf8', + writableObjectMode: true, + readableObjectMode: true, + ...opts + }; + super(opts); + this._buffer = ''; + this._lastChar = ''; + this._lastChars = ''; + this.encoding = opts.encoding; + this.delimiter = opts.delimiter;// ';' + this._bodyWrapper = ''; + this._bodyWrapperBuffer = ''; + + this.isEscape = false; + this.currentQuote = null; + this._firstDollarFound = false; + this._isBody = false; + this._isSingleLineComment = false; + this._isMultiLineComment = false; + } + + get _isComment () { + return this._isSingleLineComment || this._isMultiLineComment; + } + + _transform (chunk, encoding, next) { + for (const char of chunk.toString(this.encoding)) { + this.checkEscape(); + this._buffer += char; + this._lastChar = char; + this._lastChars += char; + + if (this._lastChars.length > this._bodyWrapper.length) + this._lastChars = this._lastChars.slice(-(this._bodyWrapper.length || 2)); + + this.checkBodyWrapper(char); + this.checkQuote(char); + this.checkCommentRow(); + const query = this.getQuery(); + + if (query) + this.push(query); + } + next(); + } + + checkEscape () { + if (this._buffer.length > 0) { + this.isEscape = this._lastChar === '\\' + ? !this.isEscape + : false; + } + } + + checkCommentRow () { + if (this._isBody) return; + + if (!this._isComment) { + if (this.currentQuote === null && this._lastChars.includes('--')) + this._isSingleLineComment = true; + + if (this.currentQuote === null && this._lastChars.includes('/*')) + this._isMultiLineComment = true; + } + else { + if (this._isSingleLineComment && (this._lastChar === '\n' || this._lastChar === '\r')) { + this._buffer = ''; + this._isSingleLineComment = false; + } + + if (this._isMultiLineComment && this._lastChars.includes('*/')) { + this._buffer = ''; + this._isMultiLineComment = false; + } + } + } + + checkBodyWrapper (char) { + if (this._isBody) + this._isBody = this._lastChars !== this._bodyWrapper; + + if (this.currentQuote === null && char === '$' && !this._firstDollarFound && !this._bodyWrapper) { + this._firstDollarFound = true; + this._bodyWrapperBuffer += char; + this._isBody = true; + } + else if (this._firstDollarFound) { + if (char === '\n' || char === ' ') { + this._firstDollarFound = false; + this._bodyWrapperBuffer = ''; + this._bodyWrapper = ''; + this._isBody = false; + return; + } + + this._bodyWrapperBuffer += char; + const isEndDollar = char === '$'; + + if (isEndDollar) { + this._firstDollarFound = false; + this._bodyWrapper = this._bodyWrapperBuffer; + this._bodyWrapperBuffer = ''; + } + } + } + + checkQuote (char) { + const isQuote = !this.isEscape && (char === '\'' || char === '"'); + if (isQuote && this.currentQuote === char) + this.currentQuote = null; + + else if (isQuote && this.currentQuote === null) + this.currentQuote = char; + } + + getQuery () { + if (this._isBody || this._isComment) + return false; + + let query = false; + let demiliterFound = false; + + if (this.currentQuote === null && this._buffer.length >= this.delimiter.length) + demiliterFound = this._lastChars.slice(-this.delimiter.length) === this.delimiter; + + if (demiliterFound) { + const parsedStr = this._buffer.trim(); + query = parsedStr; + this._buffer = ''; + this._bodyWrapper = ''; + } + + return query; + } +} diff --git a/src/main/workers/importer.js b/src/main/workers/importer.js index 672c8a11..f1c27636 100644 --- a/src/main/workers/importer.js +++ b/src/main/workers/importer.js @@ -1,5 +1,6 @@ import { ClientsFactory } from '../libs/ClientsFactory'; -import MysqlImporter from '../libs/importers/sql/MysqlImporter'; +import MySQLImporter from '../libs/importers/sql/MysqlImporter'; +import PostgreSQLImporter from '../libs/importers/sql/PostgreSQLImporter'; let importer; process.on('message', async ({ type, dbConfig, options }) => { @@ -18,7 +19,10 @@ process.on('message', async ({ type, dbConfig, options }) => { switch (options.type) { case 'mysql': case 'maria': - importer = new MysqlImporter(pool, options); + importer = new MySQLImporter(pool, options); + break; + case 'pg': + importer = new PostgreSQLImporter(pool, options); break; default: process.send({