231 lines
5.3 KiB
TypeScript
231 lines
5.3 KiB
TypeScript
/**
|
|
* 데이터베이스별 쿼리 빌더
|
|
* PostgreSQL, MySQL/MariaDB, MSSQL, Oracle 지원
|
|
*/
|
|
|
|
export type DbType = "postgresql" | "mysql" | "mariadb" | "mssql" | "oracle";
|
|
|
|
/**
|
|
* DB별 파라미터 플레이스홀더 생성
|
|
*/
|
|
export function getPlaceholder(dbType: string, index: number): string {
|
|
const normalizedType = dbType.toLowerCase();
|
|
|
|
switch (normalizedType) {
|
|
case "postgresql":
|
|
return `$${index}`;
|
|
|
|
case "mysql":
|
|
case "mariadb":
|
|
return "?";
|
|
|
|
case "mssql":
|
|
return `@p${index}`;
|
|
|
|
case "oracle":
|
|
return `:${index}`;
|
|
|
|
default:
|
|
// 기본값은 PostgreSQL
|
|
return `$${index}`;
|
|
}
|
|
}
|
|
|
|
/**
|
|
* UPDATE 쿼리 생성
|
|
*/
|
|
export function buildUpdateQuery(
|
|
dbType: string,
|
|
tableName: string,
|
|
updates: { column: string; value: any }[],
|
|
whereColumn: string = "id"
|
|
): { query: string; values: any[] } {
|
|
const normalizedType = dbType.toLowerCase();
|
|
const values: any[] = [];
|
|
|
|
// SET 절 생성
|
|
const setClause = updates
|
|
.map((update, index) => {
|
|
values.push(update.value);
|
|
const placeholder = getPlaceholder(normalizedType, values.length);
|
|
return `${update.column} = ${placeholder}`;
|
|
})
|
|
.join(", ");
|
|
|
|
// WHERE 절 생성
|
|
values.push(undefined); // whereValue는 나중에 설정
|
|
const wherePlaceholder = getPlaceholder(normalizedType, values.length);
|
|
|
|
// updated_at 처리 (DB별 NOW() 함수)
|
|
let updatedAtExpr = "NOW()";
|
|
if (normalizedType === "mssql") {
|
|
updatedAtExpr = "GETDATE()";
|
|
} else if (normalizedType === "oracle") {
|
|
updatedAtExpr = "SYSDATE";
|
|
}
|
|
|
|
const query = `
|
|
UPDATE ${tableName}
|
|
SET ${setClause}, updated_at = ${updatedAtExpr}
|
|
WHERE ${whereColumn} = ${wherePlaceholder}
|
|
`;
|
|
|
|
return { query, values };
|
|
}
|
|
|
|
/**
|
|
* INSERT 쿼리 생성
|
|
*/
|
|
export function buildInsertQuery(
|
|
dbType: string,
|
|
tableName: string,
|
|
data: Record<string, any>
|
|
): { query: string; values: any[]; returningClause: string } {
|
|
const normalizedType = dbType.toLowerCase();
|
|
const columns = Object.keys(data);
|
|
const values = Object.values(data);
|
|
|
|
// 플레이스홀더 생성
|
|
const placeholders = columns
|
|
.map((_, index) => getPlaceholder(normalizedType, index + 1))
|
|
.join(", ");
|
|
|
|
let query = `
|
|
INSERT INTO ${tableName} (${columns.join(", ")})
|
|
VALUES (${placeholders})
|
|
`;
|
|
|
|
// RETURNING/OUTPUT 절 추가 (DB별로 다름)
|
|
let returningClause = "";
|
|
if (normalizedType === "postgresql") {
|
|
query += " RETURNING id";
|
|
returningClause = "RETURNING id";
|
|
} else if (normalizedType === "mssql") {
|
|
// MSSQL은 OUTPUT 절을 INSERT와 VALUES 사이에
|
|
const insertIndex = query.indexOf("VALUES");
|
|
query =
|
|
query.substring(0, insertIndex) +
|
|
"OUTPUT INSERTED.id " +
|
|
query.substring(insertIndex);
|
|
returningClause = "OUTPUT INSERTED.id";
|
|
} else if (normalizedType === "oracle") {
|
|
query += " RETURNING id INTO :out_id";
|
|
returningClause = "RETURNING id INTO :out_id";
|
|
}
|
|
// MySQL/MariaDB는 RETURNING 없음, LAST_INSERT_ID() 사용
|
|
|
|
return { query, values, returningClause };
|
|
}
|
|
|
|
/**
|
|
* SELECT 쿼리 생성
|
|
*/
|
|
export function buildSelectQuery(
|
|
dbType: string,
|
|
tableName: string,
|
|
whereColumn: string = "id"
|
|
): { query: string; placeholder: string } {
|
|
const normalizedType = dbType.toLowerCase();
|
|
const placeholder = getPlaceholder(normalizedType, 1);
|
|
|
|
const query = `SELECT * FROM ${tableName} WHERE ${whereColumn} = ${placeholder}`;
|
|
|
|
return { query, placeholder };
|
|
}
|
|
|
|
/**
|
|
* LIMIT/OFFSET 쿼리 생성 (페이징)
|
|
*/
|
|
export function buildPaginationClause(
|
|
dbType: string,
|
|
limit?: number,
|
|
offset?: number
|
|
): string {
|
|
const normalizedType = dbType.toLowerCase();
|
|
|
|
if (!limit) {
|
|
return "";
|
|
}
|
|
|
|
if (
|
|
normalizedType === "postgresql" ||
|
|
normalizedType === "mysql" ||
|
|
normalizedType === "mariadb"
|
|
) {
|
|
// PostgreSQL, MySQL, MariaDB: LIMIT ... OFFSET ...
|
|
let clause = ` LIMIT ${limit}`;
|
|
if (offset) {
|
|
clause += ` OFFSET ${offset}`;
|
|
}
|
|
return clause;
|
|
} else if (normalizedType === "mssql") {
|
|
// MSSQL: OFFSET ... ROWS FETCH NEXT ... ROWS ONLY
|
|
if (offset) {
|
|
return ` OFFSET ${offset} ROWS FETCH NEXT ${limit} ROWS ONLY`;
|
|
} else {
|
|
return ` OFFSET 0 ROWS FETCH NEXT ${limit} ROWS ONLY`;
|
|
}
|
|
} else if (normalizedType === "oracle") {
|
|
// Oracle: ROWNUM 또는 FETCH FIRST (12c+)
|
|
if (offset) {
|
|
return ` OFFSET ${offset} ROWS FETCH NEXT ${limit} ROWS ONLY`;
|
|
} else {
|
|
return ` FETCH FIRST ${limit} ROWS ONLY`;
|
|
}
|
|
}
|
|
|
|
return "";
|
|
}
|
|
|
|
/**
|
|
* 트랜잭션 시작
|
|
*/
|
|
export function getBeginTransactionQuery(dbType: string): string {
|
|
const normalizedType = dbType.toLowerCase();
|
|
|
|
if (normalizedType === "mssql") {
|
|
return "BEGIN TRANSACTION";
|
|
}
|
|
|
|
return "BEGIN";
|
|
}
|
|
|
|
/**
|
|
* 트랜잭션 커밋
|
|
*/
|
|
export function getCommitQuery(dbType: string): string {
|
|
return "COMMIT";
|
|
}
|
|
|
|
/**
|
|
* 트랜잭션 롤백
|
|
*/
|
|
export function getRollbackQuery(dbType: string): string {
|
|
return "ROLLBACK";
|
|
}
|
|
|
|
/**
|
|
* DB 연결 테스트 쿼리
|
|
*/
|
|
export function getConnectionTestQuery(dbType: string): string {
|
|
const normalizedType = dbType.toLowerCase();
|
|
|
|
switch (normalizedType) {
|
|
case "postgresql":
|
|
return "SELECT 1";
|
|
|
|
case "mysql":
|
|
case "mariadb":
|
|
return "SELECT 1";
|
|
|
|
case "mssql":
|
|
return "SELECT 1";
|
|
|
|
case "oracle":
|
|
return "SELECT 1 FROM DUAL";
|
|
|
|
default:
|
|
return "SELECT 1";
|
|
}
|
|
}
|