├── .gitignore ├── .prettierrc ├── .idea ├── codeStyles │ ├── codeStyleConfig.xml │ └── Project.xml ├── vcs.xml ├── inspectionProfiles │ └── Project_Default.xml └── workspace.xml ├── package.json ├── .eslint.js ├── tsconfig.json ├── LICENSE ├── README.md └── src └── main.ts /.gitignore: -------------------------------------------------------------------------------- 1 | node_modules 2 | dist 3 | .idea 4 | -------------------------------------------------------------------------------- /.prettierrc: -------------------------------------------------------------------------------- 1 | { 2 | "singleQuote": true, 3 | "trailingComma": "all" 4 | } 5 | -------------------------------------------------------------------------------- /.idea/codeStyles/codeStyleConfig.xml: -------------------------------------------------------------------------------- 1 | 2 | 3 | 5 | -------------------------------------------------------------------------------- /.idea/vcs.xml: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 5 | 6 | -------------------------------------------------------------------------------- /.idea/inspectionProfiles/Project_Default.xml: -------------------------------------------------------------------------------- 1 | 2 | 3 | 6 | -------------------------------------------------------------------------------- /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "scripts": { 3 | "build": "npx tsc", 4 | "start": "node dist/main.js", 5 | "dev": "ts-node-dev --respawn --watch src src/main.ts", 6 | "lint": "eslint \"{src,apps,libs,test}/**/*.ts\" --fix" 7 | }, 8 | "dependencies": { 9 | "@types/node": "^20.8.10", 10 | "mongodb": "^6.2.0", 11 | "mysql2": "^3.6.3", 12 | "pg": "^8.11.3", 13 | "typescript": "^5.2.2" 14 | }, 15 | "devDependencies": { 16 | "@types/pg": "^8.10.9", 17 | "@typescript-eslint/eslint-plugin": "^5.0.0", 18 | "@typescript-eslint/parser": "^5.0.0", 19 | "eslint": "^8.0.1", 20 | "eslint-config-prettier": "^8.3.0", 21 | "eslint-plugin-prettier": "^4.0.0" 22 | } 23 | } 24 | -------------------------------------------------------------------------------- /.eslint.js: -------------------------------------------------------------------------------- 1 | module.exports = { 2 | parser: '@typescript-eslint/parser', 3 | parserOptions: { 4 | project: 'tsconfig.json', 5 | tsconfigRootDir: __dirname, 6 | sourceType: 'module', 7 | }, 8 | plugins: ['@typescript-eslint/eslint-plugin'], 9 | extends: [ 10 | 'plugin:@typescript-eslint/recommended', 11 | 'plugin:prettier/recommended', 12 | ], 13 | root: true, 14 | env: { 15 | node: true, 16 | jest: true, 17 | }, 18 | ignorePatterns: ['.eslintrc.js'], 19 | rules: { 20 | '@typescript-eslint/interface-name-prefix': 'off', 21 | '@typescript-eslint/explicit-function-return-type': 'off', 22 | '@typescript-eslint/explicit-module-boundary-types': 'off', 23 | '@typescript-eslint/no-explicit-any': 'off', 24 | }, 25 | }; 26 | -------------------------------------------------------------------------------- /tsconfig.json: -------------------------------------------------------------------------------- 1 | { 2 | "compilerOptions": { 3 | "outDir": "./dist", 4 | "target": "es2016", /* Set the JavaScript language version for emitted JavaScript and include compatible library declarations. */ 5 | "module": "commonjs", /* Specify what module code is generated. */ 6 | "esModuleInterop": true, /* Emit additional JavaScript to ease support for importing CommonJS modules. This enables 'allowSyntheticDefaultImports' for type compatibility. */ 7 | "forceConsistentCasingInFileNames": true, /* Ensure that casing is correct in imports. */ 8 | "strict": true, /* Skip type checking .d.ts files that are included with TypeScript. */ 9 | "skipLibCheck": true /* Skip type checking all .d.ts files. */ 10 | } 11 | } 12 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2023 @cadmax 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # MySQL to PostgreSQL Migration Script - README 2 | 3 | ## Overview 4 | This Node.js script facilitates data migration from a MySQL database to a PostgreSQL database. It automates creating tables, indexes, foreign keys, and data insertion while maintaining data integrity. 5 | 6 | ## Prerequisites 7 | - Node.js installed 8 | - MySQL and PostgreSQL servers running 9 | - `mysql2` and `pg` NPM packages installed 10 | 11 | ## Configuration 12 | Set up your database connection details at the beginning of the script: 13 | 14 | ```javascript 15 | // MySQL configuration 16 | const mysqlConfig = { 17 | host: 'localhost', 18 | user: 'root', 19 | password: 'root', 20 | database: 'users', 21 | port: 3306 22 | }; 23 | 24 | // PostgreSQL configuration 25 | const postgresConfig = { 26 | host: 'localhost', 27 | user: 'postgres', 28 | password: 'postgres', 29 | database: 'users', 30 | port: 5432 31 | }; 32 | ``` 33 | 34 | ## Features 35 | 36 | - Converts MySQL data types to PostgreSQL-compatible types. 37 | - Creates tables, primary keys, indexes, and foreign keys in PostgreSQL. 38 | - Migrates data with null value handling and type conversion. 39 | - Detailed migration process logging. 40 | 41 | ## How to Use 42 | 1. Adjust the connection settings for your databases. 43 | 2. Run npm install && npm run start 44 | 3. Monitor the process as the script migrates each table. 45 | 46 | ## Additional Information 47 | 48 | - Supports auto-increment fields, enumerations, and JSON fields. 49 | - SSL configuration for PostgreSQL is available but commented out. 50 | - Assumes no restrictive constraints in MySQL that hinder direct migration. 51 | 52 | ## Contributing 53 | Contributions for improvements or new features are welcome. Feel free to fork and submit pull requests. 54 | 55 | ## License 56 | This project is licensed under the MIT License. See the [LICENSE](LICENSE) file for more details. 57 | -------------------------------------------------------------------------------- /.idea/codeStyles/Project.xml: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 8 | 9 | 17 | 18 | 26 | 27 | 30 | 31 | 38 | 39 | 46 | 47 | 54 | 55 | 60 | 61 | -------------------------------------------------------------------------------- /.idea/workspace.xml: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 6 | 7 | 8 | 9 | 10 | 11 | 16 | 17 | 19 | 20 | 22 | 23 | 25 | { 26 | "associatedIndex": 2 27 | } 28 | 29 | 30 | 33 | { 34 | "keyToString": { 35 | "RunOnceActivity.OpenProjectViewOnStart": "true", 36 | "RunOnceActivity.ShowReadmeOnStart": "true", 37 | "WebServerToolWindowFactoryState": "false", 38 | "git-widget-placeholder": "main", 39 | "node.js.detected.package.eslint": "true", 40 | "node.js.detected.package.standard": "true", 41 | "node.js.detected.package.tslint": "true", 42 | "node.js.selected.package.eslint": "(autodetect)", 43 | "node.js.selected.package.standard": "", 44 | "node.js.selected.package.tslint": "(autodetect)", 45 | "nodejs_package_manager_path": "npm", 46 | "prettierjs.PrettierConfiguration.Package": "/Users/jeffersonmoraes/Documents/projects/guinhow01/migracao-mysql-postgres/node_modules/prettier", 47 | "rearrange.code.on.save": "true", 48 | "settings.editor.selected.configurable": "settings.javascript.prettier", 49 | "ts.external.directory.path": "/Users/jeffersonmoraes/Documents/projects/guinhow01/migracao-mysql-postgres/node_modules/typescript/lib", 50 | "vue.rearranger.settings.migration": "true" 51 | } 52 | } 53 | 54 | 55 | 56 | 57 | 58 | 59 | 60 | 61 | 62 | 1699131763166 63 | 83 | 84 | 91 | 94 | 95 | 97 | 98 | 99 | 101 | -------------------------------------------------------------------------------- /src/main.ts: -------------------------------------------------------------------------------- 1 | import mysql from 'mysql2/promise'; 2 | import { Client } from 'pg'; 3 | 4 | interface MySQLConfig { 5 | host: string; 6 | port: number; 7 | user: string; 8 | password: string; 9 | database: string; 10 | } 11 | 12 | interface PostgresConfig { 13 | host: string; 14 | user: string; 15 | password: string; 16 | database: string; 17 | port: number; 18 | ssl?: { 19 | rejectUnauthorized: boolean; 20 | } 21 | } 22 | 23 | interface TableColumn { 24 | Field: string; 25 | Type: string; 26 | Extra: string; 27 | } 28 | 29 | 30 | interface ForeignKeyConstraint { 31 | constraint_name: string; 32 | table_name: string; 33 | column_name: string; 34 | foreign_table_name: string; 35 | foreign_column_name: string; 36 | } 37 | 38 | interface TableIndex { 39 | Key_name: string; 40 | Non_unique: number; 41 | Column_name: string; 42 | } 43 | 44 | const mysqlConfig: MySQLConfig = { 45 | host: 'localhost', 46 | user: 'root', 47 | password: 'root', 48 | database: 'users', 49 | port: 3306 50 | }; 51 | 52 | const postgresConfig: PostgresConfig = { 53 | host: 'localhost', 54 | user: 'postgres', 55 | password: 'postgres', 56 | database: 'users', 57 | port: 5432, 58 | // ssl: { 59 | // rejectUnauthorized: false 60 | // } 61 | }; 62 | 63 | function mysqlTypeToPostgresType(mysqlType: string, columnExtra: string): string { 64 | // Remove qualquer coisa entre parênteses incluindo os próprios parênteses e 'unsigned' 65 | const typeWithoutLength = mysqlType 66 | .replace(/\(\d+\)/, '') 67 | .replace(/\sunsigned/i, ''); 68 | 69 | if (mysqlType.toLowerCase().includes('enum')) { 70 | return 'VARCHAR'; 71 | } 72 | 73 | if (mysqlType.toLowerCase().includes('decimal')) { 74 | return 'NUMERIC'; 75 | } 76 | 77 | if (mysqlType.toLowerCase().includes('char')) { 78 | return 'VARCHAR'; 79 | } 80 | 81 | if (columnExtra.toLowerCase().includes('auto_increment')) { 82 | if (typeWithoutLength.toLowerCase() === 'bigint') { 83 | return 'BIGSERIAL'; 84 | } else if (typeWithoutLength.toLowerCase() === 'int') { 85 | return 'SERIAL'; 86 | } else { 87 | throw new Error(`Tipo não suportado para auto_increment: ${mysqlType}`); 88 | } 89 | } 90 | 91 | switch (typeWithoutLength.toLowerCase()) { 92 | // Adicione outros tipos conforme necessário 93 | case 'int': 94 | case 'tinyint': 95 | case 'smallint': 96 | case 'mediumint': 97 | case 'bigint': 98 | return 'INTEGER'; 99 | case 'float': 100 | return 'REAL'; // No PostgreSQL, REAL é um tipo de ponto flutuante de precisão simples 101 | case 'double': 102 | case 'decimal': 103 | return 'NUMERIC'; 104 | case 'datetime': 105 | case 'timestamp': 106 | return 'TIMESTAMP'; 107 | case 'date': 108 | return 'DATE'; 109 | case 'text': 110 | case 'tinytext': 111 | case 'mediumtext': 112 | case 'longtext': 113 | return 'TEXT'; 114 | case 'char': 115 | return 'CHAR'; 116 | case 'json': 117 | return 'JSON'; 118 | case 'enum': 119 | case 'varchar': 120 | return 'VARCHAR'; // Se necessário, adicione um tamanho específico para VARCHAR 121 | default: 122 | throw new Error(`Tipo nao suportado: ${mysqlType}`); 123 | } 124 | } 125 | 126 | function getValue(value: any): any { 127 | if (value instanceof Date) { 128 | if (isNaN(value.valueOf())) { 129 | return null 130 | } 131 | } 132 | 133 | return value; 134 | } 135 | 136 | 137 | async function getMysqlForeignKeys(mysqlConnection: mysql.Connection, databaseName: string, tableName: string): Promise { 138 | const query = ` 139 | SELECT 140 | constraint_name, 141 | table_name, 142 | column_name, 143 | referenced_table_name AS foreign_table_name, 144 | referenced_column_name AS foreign_column_name 145 | FROM information_schema.key_column_usage 146 | WHERE 147 | referenced_table_schema = ? AND 148 | table_name = ? AND 149 | referenced_table_name IS NOT NULL; 150 | `; 151 | const [results] = await mysqlConnection.execute(query, [databaseName, tableName]) as unknown as [ForeignKeyConstraint[]]; 152 | return results; 153 | } 154 | 155 | async function createPostgresForeignKeys(postgresClient: Client, foreignKeys: ForeignKeyConstraint[]): Promise { 156 | try { 157 | await postgresClient.query('BEGIN'); 158 | 159 | for (const chave of foreignKeys) { 160 | const key: any = Object.keys(chave).reduce((newObj, k) => { 161 | // @ts-ignore 162 | newObj[k.toLowerCase()] = chave[k]; 163 | return newObj; 164 | }, {}); 165 | 166 | const fkExistsQuery = ` 167 | SELECT 1 168 | FROM information_schema.table_constraints 169 | WHERE constraint_type = 'FOREIGN KEY' 170 | AND table_name = $1 171 | AND constraint_name = $2; 172 | `; 173 | const fkExistsResult = await postgresClient.query(fkExistsQuery, [key.table_name, key.constraint_name]); 174 | 175 | // Se a chave estrangeira não existir, cria uma nova 176 | if (fkExistsResult.rows.length > 0) { 177 | console.info(`Chave estrangeira '${key.constraint_name}' já existe na tabela '${key.table_name}'.`); 178 | continue; 179 | } 180 | 181 | const createForeignKeyQuery = ` 182 | ALTER TABLE "${key.table_name}" 183 | ADD CONSTRAINT "${key.constraint_name}" 184 | FOREIGN KEY ("${key.column_name}") 185 | REFERENCES "${key.foreign_table_name}" ("${key.foreign_column_name}"); 186 | `; 187 | 188 | await postgresClient.query(createForeignKeyQuery); 189 | } 190 | 191 | await postgresClient.query('COMMIT'); 192 | } catch (error) { 193 | await postgresClient.query('ROLLBACK'); 194 | throw error; 195 | } 196 | } 197 | 198 | async function getMysqlTableIndexes(mysqlConnection: mysql.Connection, tableName: string): Promise { 199 | const [indexes] = await mysqlConnection.execute(`SHOW INDEX FROM ${tableName}`) as unknown as [TableIndex[]]; 200 | return indexes; 201 | } 202 | 203 | async function createPrimaryKeys(postgresClient: Client, tableName: string, primaryKeyColumns: string[]): Promise { 204 | const pkQuery = ` 205 | SELECT i.relname as index_name 206 | FROM pg_class t 207 | JOIN pg_index ix ON t.oid = ix.indrelid 208 | JOIN pg_class i ON i.oid = ix.indexrelid 209 | WHERE t.relkind = 'r' AND t.relname = $1 AND ix.indisprimary; 210 | `; 211 | const pkResult = await postgresClient.query(pkQuery, [tableName]); 212 | 213 | const hasPrimaryKey = pkResult.rows.length > 0; 214 | 215 | if (primaryKeyColumns.length > 0 && !hasPrimaryKey) { 216 | const primaryKeyQuery = `ALTER TABLE "${tableName}" ADD PRIMARY KEY (${primaryKeyColumns.join(', ')});`; 217 | await postgresClient.query(primaryKeyQuery); 218 | } 219 | } 220 | 221 | async function createPostgresIndexes(postgresClient: Client, tableName: string, mysqlIndexes: TableIndex[]): Promise { 222 | // Acumular colunas da chave primária, pois podem haver chaves primárias compostas 223 | let primaryKeyColumns: string[] = []; 224 | const indexColumnsMap: { [keyName: string]: string[] } = {}; 225 | 226 | 227 | for (const index of mysqlIndexes) { 228 | if (index.Key_name === 'PRIMARY') { 229 | // Adiciona a coluna à lista de colunas da chave primária 230 | primaryKeyColumns.push(`"${index.Column_name}"`); 231 | } else { 232 | if (!indexColumnsMap[index.Key_name]) { 233 | indexColumnsMap[index.Key_name] = []; 234 | } 235 | 236 | indexColumnsMap[index.Key_name].push(`"${index.Column_name}"`); 237 | } 238 | } 239 | 240 | for (const [keyName, columnNames] of Object.entries(indexColumnsMap)) { 241 | const indexType = mysqlIndexes.find(idx => idx.Key_name === keyName)?.Non_unique ? '' : 'UNIQUE '; 242 | const createIndexQuery = `CREATE ${indexType}INDEX IF NOT EXISTS "${keyName}" ON "${tableName}" (${columnNames.join(', ')});`; 243 | await postgresClient.query(createIndexQuery); 244 | } 245 | 246 | await createPrimaryKeys(postgresClient, tableName, primaryKeyColumns) 247 | } 248 | 249 | async function createTable (mysqlConnection: mysql.Connection, postgresClient: Client, tableName: string ): Promise { 250 | const [columns] = await mysqlConnection.execute(`DESCRIBE ${tableName}`) as unknown as [TableColumn[]]; 251 | 252 | const columnDefinitions = columns.map(column => { 253 | const columnType = mysqlTypeToPostgresType(column.Type, column.Extra); 254 | return `"${column.Field}" ${columnType}`; 255 | }).join(', ') 256 | 257 | const createTableQuery = `CREATE TABLE IF NOT EXISTS "${tableName}" (${columnDefinitions});`; 258 | 259 | await postgresClient.query(createTableQuery); 260 | } 261 | 262 | async function insertData (mysqlConnection: mysql.Connection, postgresClient: Client, tableName: string): Promise { 263 | const mysqlIndexes = await getMysqlTableIndexes(mysqlConnection, tableName); 264 | const primaryKeyColumns = mysqlIndexes.filter(index => index.Key_name === 'PRIMARY').map(index => index.Column_name); 265 | 266 | const batchSize = 1000; // Tamanho de lote 267 | 268 | const execute = async (offset: number, limit: number) => { 269 | console.info('Buscando dados da tabela', tableName, 'offset', offset, 'limit', limit) 270 | const [rows] = await mysqlConnection.execute(`SELECT * FROM ${tableName} LIMIT ${limit} OFFSET ${offset}`) as unknown as [any[]]; 271 | 272 | if (rows.length > 0) { 273 | console.info('Inserindo dados na tabela', tableName); 274 | 275 | for (let i = 0; i < rows.length; i += batchSize) { 276 | const batch = rows.slice(i, i + batchSize); 277 | const insertColumns = Object.keys(rows[0]).map(key => `"${key}"`).join(', '); 278 | 279 | let placeholderIndex = 1; 280 | const insertValues = batch.map(row => { 281 | const placeholders = Object.keys(row).map(() => `$${placeholderIndex++}`).join(', '); 282 | return `(${placeholders})`; 283 | }).join(', '); 284 | 285 | const primaryKey = primaryKeyColumns.map(col => `"${col}"`).join(', '); 286 | let conflictClause = primaryKey ? `ON CONFLICT (${primaryKey}) DO NOTHING` : 'ON CONFLICT DO NOTHING'; 287 | 288 | let insertQuery = `INSERT INTO "${tableName}" (${insertColumns}) VALUES ${insertValues} ${conflictClause};`; 289 | 290 | const rowValues = batch.flatMap(row => Object.values(row).map(getValue)); 291 | 292 | await postgresClient.query(insertQuery, rowValues); 293 | } 294 | 295 | if (rows.length === limit) { 296 | await execute(offset + limit, limit); 297 | } 298 | } 299 | } 300 | 301 | await execute(0, 1000); 302 | console.info(`Tabela '${tableName}' migrada para o PostgreSQL.`); 303 | } 304 | 305 | 306 | async function createFks (mysqlConnection: mysql.Connection, postgresClient: Client, tableName: string ): Promise { 307 | const foreignKeys = await getMysqlForeignKeys(mysqlConnection, mysqlConfig.database, tableName); 308 | 309 | await createPostgresForeignKeys(postgresClient, foreignKeys); 310 | } 311 | 312 | async function migrateData(): Promise { 313 | const skipTables: string[] = []; 314 | 315 | const mysqlConnection = await mysql.createConnection(mysqlConfig); 316 | const postgresClient = new Client(postgresConfig); 317 | await postgresClient.connect(); 318 | 319 | try { 320 | await postgresClient.query('BEGIN'); 321 | 322 | const [tables] = await mysqlConnection.execute(`SHOW TABLES`) as unknown as [any[]]; 323 | 324 | for await (const tableRow of tables) { 325 | const tableName = tableRow[`Tables_in_${mysqlConfig.database}`]; 326 | if (skipTables.includes(tableName)) continue; 327 | 328 | console.info('Criando tabela', tableName) 329 | await createTable(mysqlConnection, postgresClient, tableName) 330 | } 331 | 332 | for await (const tableRow of tables) { 333 | const tableName = tableRow[`Tables_in_${mysqlConfig.database}`]; 334 | if (skipTables.includes(tableName)) continue; 335 | 336 | console.info('Criando indexes', tableName) 337 | const mysqlIndexes = await getMysqlTableIndexes(mysqlConnection, tableName); 338 | 339 | await createPostgresIndexes(postgresClient, tableName, mysqlIndexes); 340 | } 341 | 342 | await postgresClient.query('COMMIT'); 343 | 344 | for (const tableRow of tables) { 345 | const tableName = tableRow[`Tables_in_${mysqlConfig.database}`]; 346 | 347 | if (skipTables.includes(tableName)) continue; 348 | 349 | console.info('Criando chaves estrangeiras da tabela', tableName) 350 | 351 | await createFks(mysqlConnection, postgresClient, tableName) 352 | } 353 | 354 | await postgresClient.query('BEGIN'); 355 | await postgresClient.query("SET session_replication_role = 'replica';"); 356 | 357 | for (const tableRow of tables) { 358 | const tableName = tableRow[`Tables_in_${mysqlConfig.database}`]; 359 | 360 | if (skipTables.includes(tableName)) continue; 361 | 362 | console.info('Inserindo dados da tabela', tableName) 363 | 364 | await insertData(mysqlConnection, postgresClient, tableName) 365 | } 366 | 367 | await postgresClient.query("SET session_replication_role = 'origin';"); 368 | await postgresClient.query('COMMIT'); 369 | 370 | console.info('Migração concluída.'); 371 | } catch (err) { 372 | await postgresClient.query('ROLLBACK'); 373 | console.error('Erro durante a migração, alterações desfeitas:', err); 374 | } finally { 375 | if (mysqlConnection) await mysqlConnection.end(); 376 | if (postgresClient) await postgresClient.end(); 377 | } 378 | } 379 | 380 | migrateData(); 381 | --------------------------------------------------------------------------------