From fab8909195658bc0cb5989a37599a304e1813f81 Mon Sep 17 00:00:00 2001 From: kjs Date: Wed, 1 Oct 2025 14:51:45 +0900 Subject: [PATCH] =?UTF-8?q?feat:=20=EB=A0=88=EA=B1=B0=EC=8B=9C=20src/servi?= =?UTF-8?q?ces/dataflowDiagramService.ts=20Prisma=20=EC=A0=9C=EA=B1=B0?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit 변경사항: 1. src/services/dataflowDiagramService.ts: - PrismaClient import 제거 - database/db의 query, queryOne import 추가 - 모든 Prisma 호출 Raw Query로 전환: ✅ getDataflowDiagrams: findMany + count → query + queryOne ✅ getDataflowDiagramById: findFirst → queryOne ✅ createDataflowDiagram: create → queryOne ✅ updateDataflowDiagram: update → queryOne (동적 UPDATE) ✅ deleteDataflowDiagram: delete → query ✅ copyDataflowDiagram: findFirst → queryOne 2. src/database/db.ts 생성: - backend-node/src/database/db.ts 복사 - 레거시 코드와 호환성 유지 최종 확인: - ✅ src/ 디렉토리: Prisma 호출 0개 - ✅ backend-node/ 디렉토리: Prisma 호출 0개 - ✅ 전체 프로젝트: Prisma 완전 제거 --- src/database/db.ts | 274 +++++++++++++++++++++++++ src/services/dataflowDiagramService.ts | 129 +++++++----- 2 files changed, 354 insertions(+), 49 deletions(-) create mode 100644 src/database/db.ts diff --git a/src/database/db.ts b/src/database/db.ts new file mode 100644 index 00000000..ae775525 --- /dev/null +++ b/src/database/db.ts @@ -0,0 +1,274 @@ +/** + * PostgreSQL Raw Query 기반 데이터베이스 매니저 + * + * Prisma → Raw Query 전환의 핵심 모듈 + * - Connection Pool 기반 안정적인 연결 관리 + * - 트랜잭션 지원 + * - 타입 안전성 보장 + * - 자동 재연결 및 에러 핸들링 + */ + +import { + Pool, + PoolClient, + QueryResult as PgQueryResult, + QueryResultRow, +} from "pg"; +import config from "../config/environment"; + +// PostgreSQL 연결 풀 +let pool: Pool | null = null; + +/** + * 데이터베이스 연결 풀 초기화 + */ +export const initializePool = (): Pool => { + if (pool) { + return pool; + } + + // DATABASE_URL 파싱 (postgresql://user:password@host:port/database) + const databaseUrl = config.databaseUrl; + + // URL 파싱 로직 + const dbConfig = parseDatabaseUrl(databaseUrl); + + pool = new Pool({ + host: dbConfig.host, + port: dbConfig.port, + database: dbConfig.database, + user: dbConfig.user, + password: dbConfig.password, + + // 연결 풀 설정 + min: config.nodeEnv === "production" ? 5 : 2, + max: config.nodeEnv === "production" ? 20 : 10, + + // 타임아웃 설정 + connectionTimeoutMillis: 30000, // 30초 + idleTimeoutMillis: 600000, // 10분 + + // 연결 유지 설정 + keepAlive: true, + keepAliveInitialDelayMillis: 10000, + + // 쿼리 타임아웃 + statement_timeout: 60000, // 60초 (동적 테이블 생성 등 고려) + query_timeout: 60000, + + // Application Name + application_name: "WACE-PLM-Backend", + }); + + // 연결 풀 이벤트 핸들러 + pool.on("connect", (client) => { + if (config.debug) { + console.log("✅ PostgreSQL 클라이언트 연결 생성"); + } + }); + + pool.on("acquire", (client) => { + if (config.debug) { + console.log("🔒 PostgreSQL 클라이언트 획득"); + } + }); + + pool.on("remove", (client) => { + if (config.debug) { + console.log("🗑️ PostgreSQL 클라이언트 제거"); + } + }); + + pool.on("error", (err, client) => { + console.error("❌ PostgreSQL 연결 풀 에러:", err); + }); + + console.log( + `🚀 PostgreSQL 연결 풀 초기화 완료: ${dbConfig.host}:${dbConfig.port}/${dbConfig.database}` + ); + + return pool; +}; + +/** + * DATABASE_URL 파싱 헬퍼 함수 + */ +function parseDatabaseUrl(url: string) { + // postgresql://user:password@host:port/database + const regex = /postgresql:\/\/([^:]+):([^@]+)@([^:]+):(\d+)\/(.+)/; + const match = url.match(regex); + + if (!match) { + // URL 파싱 실패 시 기본값 사용 + console.warn("⚠️ DATABASE_URL 파싱 실패, 기본값 사용"); + return { + host: "localhost", + port: 5432, + database: "ilshin", + user: "postgres", + password: "postgres", + }; + } + + return { + user: decodeURIComponent(match[1]), + password: decodeURIComponent(match[2]), + host: match[3], + port: parseInt(match[4], 10), + database: match[5], + }; +} + +/** + * 연결 풀 가져오기 + */ +export const getPool = (): Pool => { + if (!pool) { + return initializePool(); + } + return pool; +}; + +/** + * 기본 쿼리 실행 함수 + * + * @param text SQL 쿼리 문자열 (Parameterized Query) + * @param params 쿼리 파라미터 배열 + * @returns 쿼리 결과 배열 + * + * @example + * const users = await query('SELECT * FROM users WHERE user_id = $1', ['user123']); + */ +export async function query( + text: string, + params?: any[] +): Promise { + const pool = getPool(); + const client = await pool.connect(); + + try { + const startTime = Date.now(); + const result: PgQueryResult = await client.query(text, params); + const duration = Date.now() - startTime; + + if (config.debug) { + console.log("🔍 쿼리 실행:", { + query: text, + params, + rowCount: result.rowCount, + duration: `${duration}ms`, + }); + } + + return result.rows; + } catch (error: any) { + console.error("❌ 쿼리 실행 실패:", { + query: text, + params, + error: error.message, + }); + throw error; + } finally { + client.release(); + } +} + +/** + * 단일 행 조회 쿼리 (결과가 없으면 null 반환) + * + * @param text SQL 쿼리 문자열 + * @param params 쿼리 파라미터 + * @returns 단일 행 또는 null + * + * @example + * const user = await queryOne('SELECT * FROM users WHERE user_id = $1', ['user123']); + */ +export async function queryOne( + text: string, + params?: any[] +): Promise { + const rows = await query(text, params); + return rows.length > 0 ? rows[0] : null; +} + +/** + * 트랜잭션 실행 함수 + * + * @param callback 트랜잭션 내에서 실행할 함수 + * @returns 콜백 함수의 반환값 + * + * @example + * const result = await transaction(async (client) => { + * await client.query('INSERT INTO users (...) VALUES (...)', []); + * await client.query('INSERT INTO user_roles (...) VALUES (...)', []); + * return { success: true }; + * }); + */ +export async function transaction( + callback: (client: PoolClient) => Promise +): Promise { + const pool = getPool(); + const client = await pool.connect(); + + try { + await client.query("BEGIN"); + + if (config.debug) { + console.log("🔄 트랜잭션 시작"); + } + + const result = await callback(client); + + await client.query("COMMIT"); + + if (config.debug) { + console.log("✅ 트랜잭션 커밋 완료"); + } + + return result; + } catch (error: any) { + await client.query("ROLLBACK"); + + console.error("❌ 트랜잭션 롤백:", error.message); + throw error; + } finally { + client.release(); + } +} + +/** + * 연결 풀 종료 (앱 종료 시 호출) + */ +export async function closePool(): Promise { + if (pool) { + await pool.end(); + pool = null; + console.log("🛑 PostgreSQL 연결 풀 종료"); + } +} + +/** + * 연결 풀 상태 확인 + */ +export function getPoolStatus() { + const pool = getPool(); + return { + totalCount: pool.totalCount, + idleCount: pool.idleCount, + waitingCount: pool.waitingCount, + }; +} + +// Pool 직접 접근 (필요한 경우) +export { pool }; + +// 기본 익스포트 (편의성) +export default { + query, + queryOne, + transaction, + getPool, + initializePool, + closePool, + getPoolStatus, +}; diff --git a/src/services/dataflowDiagramService.ts b/src/services/dataflowDiagramService.ts index 2958353c..a73585dc 100644 --- a/src/services/dataflowDiagramService.ts +++ b/src/services/dataflowDiagramService.ts @@ -1,6 +1,4 @@ -import { PrismaClient } from "@prisma/client"; - -const prisma = new PrismaClient(); +import { query, queryOne } from "../database/db"; export interface DataflowDiagram { diagram_id: number; @@ -49,18 +47,33 @@ export class DataflowDiagramService { }; } - const [diagrams, total] = await Promise.all([ - prisma.dataflow_diagrams.findMany({ - where: whereClause, - orderBy: { created_at: "desc" }, - skip, - take: size, - }), - prisma.dataflow_diagrams.count({ - where: whereClause, - }), + // WHERE 절 구성 + const whereParts: string[] = ["company_code = $1"]; + const params: any[] = [companyCode]; + + if (searchTerm) { + whereParts.push("diagram_name ILIKE $2"); + params.push(`%${searchTerm}%`); + } + + const whereSQL = whereParts.join(" AND "); + + const [diagrams, totalResult] = await Promise.all([ + query( + `SELECT * FROM dataflow_diagrams + WHERE ${whereSQL} + ORDER BY created_at DESC + LIMIT $${params.length + 1} OFFSET $${params.length + 2}`, + [...params, size, skip] + ), + queryOne<{ count: string }>( + `SELECT COUNT(*) as count FROM dataflow_diagrams WHERE ${whereSQL}`, + params + ), ]); + const total = parseInt(totalResult?.count || "0", 10); + return { diagrams, pagination: { @@ -79,12 +92,11 @@ export class DataflowDiagramService { diagramId: number, companyCode: string ): Promise { - return await prisma.dataflow_diagrams.findFirst({ - where: { - diagram_id: diagramId, - company_code: companyCode, - }, - }); + return await queryOne( + `SELECT * FROM dataflow_diagrams + WHERE diagram_id = $1 AND company_code = $2`, + [diagramId, companyCode] + ); } /** @@ -93,14 +105,19 @@ export class DataflowDiagramService { async createDataflowDiagram( data: CreateDataflowDiagramData ): Promise { - return await prisma.dataflow_diagrams.create({ - data: { - diagram_name: data.diagram_name, - relationships: data.relationships, - company_code: data.company_code, - created_by: data.created_by, - }, - }); + const result = await queryOne( + `INSERT INTO dataflow_diagrams + (diagram_name, relationships, company_code, created_by, created_at, updated_at) + VALUES ($1, $2, $3, $4, NOW(), NOW()) + RETURNING *`, + [ + data.diagram_name, + JSON.stringify(data.relationships), + data.company_code, + data.created_by || null, + ] + ); + return result!; } /** @@ -120,17 +137,33 @@ export class DataflowDiagramService { return null; } - return await prisma.dataflow_diagrams.update({ - where: { - diagram_id: diagramId, - }, - data: { - ...(data.diagram_name && { diagram_name: data.diagram_name }), - ...(data.relationships && { relationships: data.relationships }), - ...(data.updated_by && { updated_by: data.updated_by }), - updated_at: new Date(), - }, - }); + // 동적 UPDATE 쿼리 생성 + const updateFields: string[] = ["updated_at = NOW()"]; + const params: any[] = []; + let paramIndex = 1; + + if (data.diagram_name !== undefined) { + updateFields.push(`diagram_name = $${paramIndex++}`); + params.push(data.diagram_name); + } + if (data.relationships !== undefined) { + updateFields.push(`relationships = $${paramIndex++}`); + params.push(JSON.stringify(data.relationships)); + } + if (data.updated_by !== undefined) { + updateFields.push(`updated_by = $${paramIndex++}`); + params.push(data.updated_by); + } + + params.push(diagramId); + + return await queryOne( + `UPDATE dataflow_diagrams + SET ${updateFields.join(", ")} + WHERE diagram_id = $${paramIndex} + RETURNING *`, + params + ); } /** @@ -149,11 +182,10 @@ export class DataflowDiagramService { return false; } - await prisma.dataflow_diagrams.delete({ - where: { - diagram_id: diagramId, - }, - }); + await query( + `DELETE FROM dataflow_diagrams WHERE diagram_id = $1`, + [diagramId] + ); return true; } @@ -184,12 +216,11 @@ export class DataflowDiagramService { while (true) { copyName = `${baseName} (${counter})`; - const existing = await prisma.dataflow_diagrams.findFirst({ - where: { - company_code: companyCode, - diagram_name: copyName, - }, - }); + const existing = await queryOne( + `SELECT * FROM dataflow_diagrams + WHERE company_code = $1 AND diagram_name = $2`, + [companyCode, copyName] + ); if (!existing) break; counter++;