#!/usr/bin/env node const fs = require('fs'); const path = require('path'); const config = require('./config'); /** * PostgreSQL到达梦数据库SQL转换器 */ class PG2DMConverter { constructor() { this.conversionLog = []; this.warnings = []; this.stats = { dataTypes: 0, sequences: 0, collates: 0, indexes: 0, coalesceIndexes: 0 }; } /** * 记录转换日志 */ log(message, type = 'INFO') { const timestamp = new Date().toISOString(); this.conversionLog.push({ timestamp, type, message }); console.log(`[${type}] ${message}`); } /** * 记录警告 */ warn(message) { this.warnings.push(message); this.log(message, 'WARN'); } /** * 转换数据类型 */ convertDataTypes(sql) { let converted = sql; // 1. 转换基本类型(包括浮点类型和时间戳类型) const typePattern = /\b(int8|int4|int2|numeric|bool|float8|float4|float|timestamptz|text|bpchar)\b/gi; converted = converted.replace(typePattern, (match) => { const lowerMatch = match.toLowerCase(); if (config.dataTypeMapping[lowerMatch]) { this.stats.dataTypes++; return config.dataTypeMapping[lowerMatch]; } return match; }); // 2. 处理timestamp精度参数 // PostgreSQL: timestamp(6) 或 timestamp(0) // 达梦: TIMESTAMP (不支持精度参数,直接移除) converted = converted.replace(/\btimestamp\s*\(\s*\d+\s*\)/gi, (match) => { this.log(`移除timestamp精度参数: ${match} -> TIMESTAMP`); return `TIMESTAMP`; }); // 3. 移除时区子句 // PostgreSQL: TIMESTAMP without time zone / TIMESTAMP with time zone // 达梦: TIMESTAMP (不支持时区子句) converted = converted.replace(/TIMESTAMP\s+(without|with)\s+time\s+zone/gi, 'TIMESTAMP'); const timezoneMatches = sql.match(/TIMESTAMP\s+(without|with)\s+time\s+zone/gi); if (timezoneMatches) { this.log(`移除 ${timezoneMatches.length} 个TIMESTAMP时区子句`); } // 4. 修正DECIMAL精度超出范围 // 达梦DECIMAL最大精度38位,PostgreSQL可以到1000位 converted = converted.replace(/DECIMAL\s*\((\d+)\s*,\s*(\d+)\)/gi, (match, precision, scale) => { const p = parseInt(precision); const s = parseInt(scale); if (p > 38) { this.warn(`DECIMAL(${p},${s}) 精度超出达梦限制(最大38),已调整为DECIMAL(38,${s})`); return `DECIMAL(38,${s})`; } return match; }); return converted; } /** * 转换序列为IDENTITY */ convertSequences(sql) { let converted = sql; // 第一步:匹配完整的列定义格式 // "id" BIGINT NOT NULL DEFAULT nextval(...) // 使用更宽松的正则,匹配任意数据类型 const fullPattern = /"(\w+)"\s+([A-Z]+(?:\([^)]+\))?)\s+NOT\s+NULL\s+DEFAULT\s+nextval\s*\([^)]+\)/gi; converted = converted.replace(fullPattern, (match, colName, dataType) => { this.stats.sequences++; this.log(`转换列定义: ${colName} ${dataType} -> IDENTITY(1,1)`); return `"${colName}" ${dataType} IDENTITY(1, 1) NOT NULL`; }); // 第二步:处理其他格式,直接移除 DEFAULT nextval(...) const defaultPattern = /DEFAULT\s+nextval\s*\([^)]+\)/gi; converted = converted.replace(defaultPattern, (match) => { this.stats.sequences++; this.log(`移除序列DEFAULT: ${match.substring(0, 50)}...`); return 'IDENTITY(1, 1)'; }); return converted; } /** * 移除COLLATE子句 */ removeCollate(sql) { let converted = sql; // 匹配所有COLLATE格式 // COLLATE "pg_catalog"."default" // COLLATE "default" // COLLATE pg_catalog."default" const collatePattern1 = /COLLATE\s+"pg_catalog"\."[^"]+"/gi; const collatePattern2 = /COLLATE\s+"[^"]+"/gi; const collatePattern3 = /COLLATE\s+\w+/gi; let totalMatches = 0; const matches1 = sql.match(collatePattern1); if (matches1) totalMatches += matches1.length; const matches2 = sql.match(collatePattern2); if (matches2) totalMatches += matches2.length; if (totalMatches > 0) { this.stats.collates += totalMatches; this.log(`移除 ${totalMatches} 个COLLATE子句`); } // 按顺序移除,先移除复杂的,再移除简单的 converted = converted.replace(collatePattern1, ''); converted = converted.replace(collatePattern2, ''); converted = converted.replace(collatePattern3, ''); return converted; } /** * 移除PostgreSQL类型转换语法 */ removeTypeCasts(sql) { let converted = sql; // 移除 ::type 语法 const typeCastPattern = /::(character\s+varying|varchar|text|integer|bigint|smallint|numeric|decimal|timestamp|date|time|boolean|regclass)/gi; const matches = sql.match(typeCastPattern); if (matches) { this.log(`移除 ${matches.length} 个PostgreSQL类型转换`); } converted = converted.replace(typeCastPattern, ''); return converted; } /** * 移除pg_catalog模式前缀和数据类型引号 */ removePgCatalog(sql) { let converted = sql; // 移除 "pg_catalog". 前缀 const catalogPattern = /"pg_catalog"\./gi; const matches = sql.match(catalogPattern); if (matches) { this.log(`移除 ${matches.length} 个pg_catalog前缀`); } converted = converted.replace(catalogPattern, ''); // 转换PostgreSQL布尔值为达梦格式(在移除引号之前) converted = converted.replace(/\bDEFAULT\s+false\b/gi, 'DEFAULT 0'); converted = converted.replace(/\bDEFAULT\s+true\b/gi, 'DEFAULT 1'); return converted; } /** * 移除数据类型的引号 */ removeTypeQuotes(sql) { let converted = sql; // 移除引号中的数据类型(达梦不需要给类型加引号) // 1. 先处理带括号的类型:VARCHAR(8000), DECIMAL(20,6), CHAR(10)等 converted = converted.replace(/\s"(VARCHAR|CHAR|DECIMAL|NUMERIC)\s*\([^)]+\)"\s/gi, ' $1 '); converted = converted.replace(/\s"(VARCHAR|CHAR|DECIMAL|NUMERIC)\s*\([^)]+\)"([,\n\r])/gi, ' $1$2'); // 2. 再处理简单类型(包括不带长度的CHAR) converted = converted.replace(/\s"(BIGINT|INT|SMALLINT|TINYINT|VARCHAR|CHAR|TEXT|DATE|TIME|TIMESTAMP|BIT|BOOLEAN|BOOL|BLOB|CLOB|DOUBLE|REAL)"\s/gi, ' $1 '); converted = converted.replace(/\s"(BIGINT|INT|SMALLINT|TINYINT|VARCHAR|CHAR|TEXT|DATE|TIME|TIMESTAMP|BIT|BOOLEAN|BOOL|BLOB|CLOB|DOUBLE|REAL)"([,\n\r])/gi, ' $1$2'); this.log('移除数据类型引号'); return converted; } /** * 移除空的或不完整的PARTITION BY子句 */ removeEmptyPartition(sql) { let converted = sql; let removedCount = 0; // 1. 移除 PARTITION BY LIST (column) 后面没有具体分区的情况 // 格式: )\nPARTITION BY LIST (\n "column"\n)\n; const listPattern = /\)\s*PARTITION\s+BY\s+LIST\s*\([^)]+\)\s*;/gi; const listMatches = converted.match(listPattern); if (listMatches) { converted = converted.replace(listPattern, ');'); removedCount += listMatches.length; this.log(`移除 ${listMatches.length} 个空的PARTITION BY LIST子句`); } // 2. 移除 PARTITION BY RANGE (column) 后面没有具体分区的情况 const rangePattern = /\)\s*PARTITION\s+BY\s+RANGE\s*\([^)]+\)\s*;/gi; const rangeMatches = converted.match(rangePattern); if (rangeMatches) { converted = converted.replace(rangePattern, ');'); removedCount += rangeMatches.length; this.log(`移除 ${rangeMatches.length} 个空的PARTITION BY RANGE子句`); } // 3. 移除 PARTITION BY HASH (column) 后面没有具体分区的情况 const hashPattern = /\)\s*PARTITION\s+BY\s+HASH\s*\([^)]+\)\s*;/gi; const hashMatches = converted.match(hashPattern); if (hashMatches) { converted = converted.replace(hashPattern, ');'); removedCount += hashMatches.length; this.log(`移除 ${hashMatches.length} 个空的PARTITION BY HASH子句`); } // 4. 移除空括号的PARTITION BY converted = converted.replace(/\)\s*PARTITION\s+BY\s+\([^)]*\)\s*;/gi, ');\n'); if (removedCount > 0) { this.log(`总共移除 ${removedCount} 个空的PARTITION BY子句`); } return converted; } /** * 移除所有COMMENT语句(达梦不支持COMMENT ON语法) */ removeIndexComments(sql) { let converted = sql; let totalRemoved = 0; // 1. 移除 COMMENT ON COLUMN const columnPattern = /COMMENT\s+ON\s+COLUMN\s+"[^"]+"\."[^"]+"\."[^"]+"\s+IS\s+'[^']*'\s*;/gi; const columnMatches = sql.match(columnPattern); if (columnMatches) { converted = converted.replace(columnPattern, ''); totalRemoved += columnMatches.length; this.log(`移除 ${columnMatches.length} 个列注释`); } // 2. 移除 COMMENT ON TABLE const tablePattern = /COMMENT\s+ON\s+TABLE\s+"[^"]+"\."[^"]+"\s+IS\s+'[^']*'\s*;/gi; const tableMatches = converted.match(tablePattern); if (tableMatches) { converted = converted.replace(tablePattern, ''); totalRemoved += tableMatches.length; this.log(`移除 ${tableMatches.length} 个表注释`); } // 3. 移除 COMMENT ON INDEX const indexPattern = /COMMENT\s+ON\s+INDEX\s+"[^"]+"\."[^"]+"\s+IS\s+'[^']*'\s*;/gi; const indexMatches = converted.match(indexPattern); if (indexMatches) { converted = converted.replace(indexPattern, ''); totalRemoved += indexMatches.length; this.log(`移除 ${indexMatches.length} 个索引注释`); } if (totalRemoved > 0) { this.log(`总共移除 ${totalRemoved} 个COMMENT语句(达梦不支持)`); // 清理可能产生的多余空行 converted = converted.replace(/\n\n\n+/g, '\n\n'); } return converted; } /** * 移除分区附加语句(达梦不支持ATTACH PARTITION) */ removeAttachPartition(sql) { let converted = sql; // 匹配 ALTER TABLE ... ATTACH PARTITION ... FOR VALUES ...; const attachPattern = /ALTER\s+TABLE\s+"[^"]+"\."[^"]+"\s+ATTACH\s+PARTITION\s+"[^"]+"\."[^"]+"\s+FOR\s+VALUES[^;]*;/gi; const matches = sql.match(attachPattern); if (matches) { this.log(`移除 ${matches.length} 个ATTACH PARTITION语句(达梦不支持)`); converted = converted.replace(attachPattern, ''); // 清理多余空行 converted = converted.replace(/\n\n\n+/g, '\n\n'); } return converted; } /** * 移除与主键约束同名的唯一索引 * PostgreSQL导出时会同时包含索引和约束,但在达梦中会冲突 */ removeDuplicatePrimaryKeyIndexes(sql) { let converted = sql; let removedCount = 0; // 1. 提取所有主键约束的名称 const pkConstraintPattern = /ADD\s+CONSTRAINT\s+"([^"]+)"\s+PRIMARY\s+KEY/gi; const constraintNames = new Set(); let match; while ((match = pkConstraintPattern.exec(sql)) !== null) { constraintNames.add(match[1]); } if (constraintNames.size === 0) { return converted; } // 2. 移除与这些约束同名的UNIQUE INDEX constraintNames.forEach(constraintName => { // 匹配: CREATE UNIQUE INDEX "constraint_name" ON ...; const indexPattern = new RegExp( `CREATE\\s+UNIQUE\\s+INDEX\\s+"${constraintName}"\\s+ON\\s+[^;]+;`, 'gi' ); const indexMatches = converted.match(indexPattern); if (indexMatches) { converted = converted.replace(indexPattern, ''); removedCount += indexMatches.length; this.log(`移除与主键约束同名的唯一索引: ${constraintName}`); } }); if (removedCount > 0) { this.log(`总共移除 ${removedCount} 个与主键同名的唯一索引`); // 清理多余空行 converted = converted.replace(/\n\n\n+/g, '\n\n'); } return converted; } /** * 简化索引语法 */ simplifyIndexSyntax(sql) { let converted = sql; // 移除USING btree/hash/gist等 converted = converted.replace(/USING\s+\w+/gi, ''); // 移除操作符类 "pg_catalog"."text_ops" 或 "text_ops" // 包括各种格式:int8_ops, text_ops, varchar_ops等 converted = converted.replace(/"pg_catalog"\."[^"]+_ops"/gi, ''); converted = converted.replace(/\s+"[^"]+_ops"/gi, ''); // 移除NULLS LAST/FIRST(在移除ASC/DESC之前) converted = converted.replace(/\s+NULLS\s+(FIRST|LAST)/gi, ''); // 移除ASC/DESC(如果需要保留可以注释掉) // converted = converted.replace(/\s+(ASC|DESC)/gi, ''); this.stats.indexes++; return converted; } /** * 移除索引中的重复列 */ removeDuplicateIndexColumns(sql) { let converted = sql; // 匹配CREATE INDEX语句 const indexPattern = /(CREATE\s+(?:UNIQUE\s+)?INDEX\s+"[^"]+"\s+ON\s+"[^"]+"\."[^"]+"\s*\()([\s\S]*?)(\);)/gi; converted = converted.replace(indexPattern, (match, prefix, columns, suffix) => { // 解析列定义 const columnList = columns.split(',').map(col => col.trim()); const seen = new Set(); const uniqueColumns = []; columnList.forEach(col => { // 提取列名(去除ASC/DESC等) const colNameMatch = col.match(/"(\w+)"/); if (colNameMatch) { const colName = colNameMatch[1].toLowerCase(); if (!seen.has(colName)) { seen.add(colName); uniqueColumns.push(col); } else { this.warn(`索引中发现重复列: ${colNameMatch[1]},已自动移除重复项`); } } else { // COALESCE等表达式,直接保留 uniqueColumns.push(col); } }); return prefix + '\n ' + uniqueColumns.join(',\n ') + '\n' + suffix; }); return converted; } /** * 处理COALESCE函数索引 */ processCoalesceIndexes(sql) { let converted = sql; // 第一步:移除PostgreSQL类型转换语法 ::type converted = converted.replace(/::(character\s+varying|varchar|text|integer|bigint|smallint)/gi, ''); // 第二步:处理COALESCE函数索引 const coalesceIndexPattern = /CREATE\s+(?:UNIQUE\s+)?INDEX\s+"([^"]+)"\s+ON\s+"[^"]+"\."[^"]+"\s*\(([\s\S]*?)\);/gi; converted = converted.replace(coalesceIndexPattern, (match, indexName, columns) => { const coalesceCount = (columns.match(/COALESCE\s*\(/gi) || []).length; if (coalesceCount > 0) { this.stats.coalesceIndexes++; if (coalesceCount > config.coalesceThreshold) { this.warn( `索引 ${indexName} 包含 ${coalesceCount} 个COALESCE函数,可能超过达梦816字符限制,已自动简化` ); } else { this.log(`处理索引 ${indexName} 中的 ${coalesceCount} 个COALESCE函数`); } // 移除COALESCE,保留原始列名 // 匹配多种格式: // COALESCE("col_name", '-999') // COALESCE(col_name, '-999') let simplifiedColumns = columns.replace( /COALESCE\s*\(\s*"?(\w+)"?\s*,\s*'[^']+'\s*\)/gi, '"$1"' ); // 移除多余的空格和换行 simplifiedColumns = simplifiedColumns.replace(/\s+/g, ' ').trim(); return match.replace(columns, simplifiedColumns); } return match; }); return converted; } /** * 添加转换说明注释 */ addConversionHeader(sql, originalFile) { const header = `/* Converted to DaMeng SQL by pg2dm-converter Source File : ${path.basename(originalFile)} Source Server Type : PostgreSQL Target Server Type : DaMeng 8 Conversion Date : ${new Date().toLocaleString('zh-CN')} Conversion Summary: - Data Types Converted: ${this.stats.dataTypes} - Sequences -> IDENTITY: ${this.stats.sequences} - COLLATE Clauses Removed: ${this.stats.collates} - Indexes Simplified: ${this.stats.indexes} - COALESCE Indexes Processed: ${this.stats.coalesceIndexes} */ `; return header + sql; } /** * 主转换方法 */ convert(sql, originalFile = 'input.sql') { this.log('开始转换PostgreSQL SQL到达梦语法'); let converted = sql; // 1. 移除pg_catalog模式前缀(必须在最前面) this.log('步骤1: 移除pg_catalog模式前缀...'); converted = this.removePgCatalog(converted); // 2. 转换数据类型 this.log('步骤2: 转换数据类型...'); converted = this.convertDataTypes(converted); // 3. 转换序列为IDENTITY this.log('步骤3: 转换序列为IDENTITY...'); converted = this.convertSequences(converted); // 4. 移除PostgreSQL类型转换 this.log('步骤4: 移除PostgreSQL类型转换...'); converted = this.removeTypeCasts(converted); // 5. 移除COLLATE子句 this.log('步骤5: 移除COLLATE子句...'); converted = this.removeCollate(converted); // 6. 移除数据类型引号 this.log('步骤6: 移除数据类型引号...'); converted = this.removeTypeQuotes(converted); // 7. 移除空的PARTITION BY子句 this.log('步骤7: 移除空的PARTITION BY子句...'); converted = this.removeEmptyPartition(converted); // 8. 简化索引语法 this.log('步骤8: 简化索引语法...'); converted = this.simplifyIndexSyntax(converted); // 9. 移除索引中的重复列 this.log('步骤9: 移除索引中的重复列...'); converted = this.removeDuplicateIndexColumns(converted); // 10. 处理COALESCE函数索引 this.log('步骤10: 处理COALESCE函数索引...'); converted = this.processCoalesceIndexes(converted); // 11. 移除索引注释(达梦不支持COMMENT ON INDEX) this.log('步骤11: 移除索引注释...'); converted = this.removeIndexComments(converted); // 12. 移除分区附加语句(达梦不支持ATTACH PARTITION) this.log('步骤12: 移除分区附加语句...'); converted = this.removeAttachPartition(converted); // 13. 移除与主键约束同名的唯一索引(避免冲突) this.log('步骤13: 移除与主键约束同名的唯一索引...'); converted = this.removeDuplicatePrimaryKeyIndexes(converted); // 14. 添加转换说明 if (config.output.addConversionComment) { converted = this.addConversionHeader(converted, originalFile); } this.log('转换完成!'); return converted; } /** * 生成转换日志文件 */ generateLogFile(outputPath) { const logContent = { timestamp: new Date().toISOString(), stats: this.stats, warnings: this.warnings, logs: this.conversionLog }; const logFile = outputPath.replace('.sql', '_conversion.log.json'); fs.writeFileSync(logFile, JSON.stringify(logContent, null, 2)); this.log(`转换日志已保存: ${logFile}`); } } /** * 确保目录存在 */ function ensureDir(dirPath) { if (!fs.existsSync(dirPath)) { fs.mkdirSync(dirPath, { recursive: true }); } } /** * 转换单个文件 */ function convertSingleFile(inputFile, outputFile) { // 读取输入文件 console.log(`\n读取文件: ${inputFile}`); const sqlContent = fs.readFileSync(inputFile, 'utf8'); // 转换 const converter = new PG2DMConverter(); const convertedSql = converter.convert(sqlContent, inputFile); // 确定输出文件路径 if (!outputFile) { outputFile = path.join( './output', path.basename(inputFile, '.sql') + '_dm.sql' ); } // 写入输出文件 ensureDir(path.dirname(outputFile)); fs.writeFileSync(outputFile, convertedSql, 'utf8'); console.log(`✓ 转换完成: ${outputFile}`); // 生成日志 if (config.output.generateLog) { converter.generateLogFile(outputFile); } // 显示警告 if (converter.warnings.length > 0) { console.log('⚠ 警告信息:'); converter.warnings.forEach((warn, i) => { console.log(` ${i + 1}. ${warn}`); }); } // 显示统计 console.log('转换统计:'); console.log(` - 数据类型转换: ${converter.stats.dataTypes}`); console.log(` - 序列转IDENTITY: ${converter.stats.sequences}`); console.log(` - COLLATE移除: ${converter.stats.collates}`); console.log(` - 索引简化: ${converter.stats.indexes}`); console.log(` - COALESCE索引处理: ${converter.stats.coalesceIndexes}`); return { success: true, warnings: converter.warnings.length }; } /** * 批量转换目录下所有SQL文件 */ function batchConvert(inputDir) { console.log(`\n📁 批量转换目录: ${inputDir}`); console.log('='.repeat(50)); // 读取目录下所有.sql文件 const files = fs.readdirSync(inputDir) .filter(file => file.toLowerCase().endsWith('.sql')) .map(file => path.join(inputDir, file)); if (files.length === 0) { console.log(`\n⚠ 目录中没有找到.sql文件: ${inputDir}`); return; } console.log(`\n找到 ${files.length} 个SQL文件`); let successCount = 0; let failCount = 0; let totalWarnings = 0; // 逐个转换 files.forEach((file, index) => { try { console.log(`\n[${index + 1}/${files.length}] 处理: ${path.basename(file)}`); console.log('-'.repeat(50)); const result = convertSingleFile(file, null); successCount++; totalWarnings += result.warnings; } catch (error) { console.error(`✗ 转换失败: ${error.message}`); failCount++; } }); // 显示总结 console.log('\n' + '='.repeat(50)); console.log('📊 批量转换完成'); console.log('='.repeat(50)); console.log(`✓ 成功: ${successCount} 个文件`); if (failCount > 0) { console.log(`✗ 失败: ${failCount} 个文件`); } if (totalWarnings > 0) { console.log(`⚠ 总警告: ${totalWarnings} 条`); } console.log(`📂 输出目录: ./output`); } /** * 主函数 */ function main() { const args = process.argv.slice(2); // 确保input和output目录存在 ensureDir('./input'); ensureDir('./output'); // 无参数:批量处理input目录 if (args.length === 0) { if (fs.existsSync('./input')) { batchConvert('./input'); } else { console.log(` PostgreSQL到达梦数据库SQL转换器 ====================================== 使用方法: node converter.js # 批量转换input目录下所有.sql文件 node converter.js # 转换单个文件 node converter.js # 批量转换指定目录 node converter.js # 指定输出文件 示例: node converter.js # 批量转换input/*.sql node converter.js input/schema.sql # 转换单个文件 node converter.js ./mydata # 批量转换mydata目录 node converter.js input/schema.sql output/schema_dm.sql 说明: - 批量模式会自动在output目录生成 *_dm.sql 文件 - 会自动生成转换日志文件 *_conversion.log.json - 批量模式会显示详细的进度和统计信息 `); } return; } const inputPath = args[0]; // 检查路径是否存在 if (!fs.existsSync(inputPath)) { console.error(`✗ 错误: 路径不存在: ${inputPath}`); process.exit(1); } // 检查是文件还是目录 const stat = fs.statSync(inputPath); if (stat.isDirectory()) { // 批量转换目录 batchConvert(inputPath); } else if (stat.isFile()) { // 单个文件转换 const outputFile = args[1]; try { convertSingleFile(inputPath, outputFile); console.log('\n✓ 转换成功!'); } catch (error) { console.error(`\n✗ 转换失败: ${error.message}`); console.error(error.stack); process.exit(1); } } else { console.error(`✗ 错误: 不支持的路径类型: ${inputPath}`); process.exit(1); } } // 运行主函数 if (require.main === module) { main(); } module.exports = PG2DMConverter;