// 检查数据库结构的脚本 const { Client } = require('pg'); const dotenv = require('dotenv'); const path = require('path'); const fs = require('fs'); // 加载环境变量 dotenv.config({ path: path.resolve(__dirname, '../../.env') }); // 获取数据库连接字符串 const databaseUrl = process.env.DATABASE_URL; if (!databaseUrl) { console.error('缺少数据库连接字符串。请确保.env文件中包含DATABASE_URL'); process.exit(1); } // 定义输出目录 const DB_REPORTS_DIR = path.resolve(__dirname, '../db-reports'); // 连接数据库 async function connect() { console.log('使用PostgreSQL连接字符串连接数据库...'); // 创建PostgreSQL客户端 const client = new Client({ connectionString: databaseUrl, }); try { await client.connect(); console.log('成功连接到数据库'); return client; } catch (error) { console.error('连接数据库失败:', error); throw error; } } // 断开数据库连接 async function disconnect(client) { try { await client.end(); console.log('已断开数据库连接'); } catch (error) { console.error('断开数据库连接失败:', error); } } // 获取所有表 async function getAllTables(client) { console.log('\n获取所有表...'); try { const query = ` SELECT table_name FROM information_schema.tables WHERE table_schema = 'public' ORDER BY table_name; `; const result = await client.query(query); if (!result.rows || result.rows.length === 0) { console.log('没有找到任何表'); return null; } console.log('找到以下表:'); result.rows.forEach(row => { console.log(` - ${row.table_name}`); }); return result.rows.map(row => row.table_name); } catch (error) { console.error('获取所有表时出错:', error); return null; } } // 获取表结构 async function getTableSchema(client, tableName) { console.log(`\n获取表 ${tableName} 的结构...`); try { // 获取基本列信息 const columnsQuery = ` SELECT column_name, data_type, is_nullable, column_default, character_maximum_length, numeric_precision, numeric_scale FROM information_schema.columns WHERE table_schema = 'public' AND table_name = $1 ORDER BY ordinal_position; `; const columnsResult = await client.query(columnsQuery, [tableName]); if (!columnsResult.rows || columnsResult.rows.length === 0) { console.log(`表 ${tableName} 不存在或没有列`); return null; } // 获取主键信息 const primaryKeyQuery = ` SELECT kcu.column_name FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.constraint_type = 'PRIMARY KEY' AND tc.table_schema = 'public' AND tc.table_name = $1 ORDER BY kcu.ordinal_position; `; const primaryKeyResult = await client.query(primaryKeyQuery, [tableName]); // 获取外键信息 const foreignKeysQuery = ` SELECT kcu.column_name, ccu.table_name AS foreign_table_name, ccu.column_name AS foreign_column_name FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema JOIN information_schema.constraint_column_usage ccu ON tc.constraint_name = ccu.constraint_name AND tc.table_schema = ccu.table_schema WHERE tc.constraint_type = 'FOREIGN KEY' AND tc.table_schema = 'public' AND tc.table_name = $1; `; const foreignKeysResult = await client.query(foreignKeysQuery, [tableName]); // 获取索引信息 const indexesQuery = ` SELECT indexname, indexdef FROM pg_indexes WHERE schemaname = 'public' AND tablename = $1; `; const indexesResult = await client.query(indexesQuery, [tableName]); // 输出列信息 console.log(`表 ${tableName} 的列:`); columnsResult.rows.forEach(column => { console.log(` - ${column.column_name} (${column.data_type}${ column.character_maximum_length ? `(${column.character_maximum_length})` : (column.numeric_precision ? `(${column.numeric_precision},${column.numeric_scale})` : '') }, ${column.is_nullable === 'YES' ? '可为空' : '不可为空'}, 默认值: ${column.column_default || 'NULL'})`); }); // 输出主键信息 if (primaryKeyResult.rows.length > 0) { console.log(` 主键: ${primaryKeyResult.rows.map(row => row.column_name).join(', ')}`); } else { console.log(' 主键: 无'); } // 输出外键信息 if (foreignKeysResult.rows.length > 0) { console.log(' 外键:'); foreignKeysResult.rows.forEach(fk => { console.log(` - ${fk.column_name} -> ${fk.foreign_table_name}.${fk.foreign_column_name}`); }); } else { console.log(' 外键: 无'); } // 输出索引信息 if (indexesResult.rows.length > 0) { console.log(' 索引:'); indexesResult.rows.forEach(idx => { console.log(` - ${idx.indexname}: ${idx.indexdef}`); }); } else { console.log(' 索引: 无'); } return { columns: columnsResult.rows, primaryKey: primaryKeyResult.rows, foreignKeys: foreignKeysResult.rows, indexes: indexesResult.rows }; } catch (error) { console.error(`获取表 ${tableName} 结构时出错:`, error); return null; } } // 获取表数据示例 async function getTableDataSample(client, tableName, limit = 5) { console.log(`\n获取表 ${tableName} 的数据示例 (最多 ${limit} 行)...`); try { const query = ` SELECT * FROM "${tableName}" LIMIT $1; `; const result = await client.query(query, [limit]); if (!result.rows || result.rows.length === 0) { console.log(`表 ${tableName} 中没有数据`); return null; } console.log(`表 ${tableName} 的数据示例:`); result.rows.forEach((row, index) => { console.log(` 行 ${index + 1}:`); Object.entries(row).forEach(([key, value]) => { console.log(` ${key}: ${value}`); }); }); return result.rows; } catch (error) { console.error(`获取表 ${tableName} 数据示例时出错:`, error); return null; } } // 主函数 async function main() { let client = null; let outputBuffer = ''; const originalConsoleLog = console.log; // 重定向console.log到buffer和控制台 console.log = function() { // 调用原始的console.log originalConsoleLog.apply(console, arguments); // 写入到buffer outputBuffer += Array.from(arguments).join(' ') + '\n'; }; try { // 连接数据库 client = await connect(); // 获取所有表 const tables = await getAllTables(client); if (!tables) { console.error('无法获取表列表'); process.exit(1); } console.log('\n所有PostgreSQL表:'); console.log(tables.join(', ')); // 获取所有表的结构,而不只是特定表 for (const tableName of tables) { await getTableSchema(client, tableName); // 移除数据示例检查 // await getTableDataSample(client, tableName); } console.log('\n数据库结构检查完成'); // 保存输出到指定目录 const timestamp = new Date().toISOString().replace(/[:.]/g, '-'); // 确保目录存在 if (!fs.existsSync(DB_REPORTS_DIR)) { fs.mkdirSync(DB_REPORTS_DIR, { recursive: true }); } const outputPath = path.join(DB_REPORTS_DIR, `postgres-schema-${timestamp}.log`); fs.writeFileSync(outputPath, outputBuffer); originalConsoleLog(`结果已保存到: ${outputPath}`); } catch (error) { console.error('检查数据库结构时出错:', error); process.exit(1); } finally { // 恢复原始的console.log console.log = originalConsoleLog; // 关闭数据库连接 if (client) { await disconnect(client); } } } // 导出函数 module.exports = { connect, disconnect, getAllTables, getTableSchema, getTableDataSample, main }; // 如果直接运行此脚本,则执行main函数 if (require.main === module) { main().catch(error => { console.error('运行脚本时出错:', error); process.exit(1); }); }