ERP-node/backend-node/src/services/taxInvoiceService.ts

785 lines
22 KiB
TypeScript

/**
* 세금계산서 서비스
* 세금계산서 CRUD 및 비즈니스 로직 처리
*/
import { query, transaction } from "../database/db";
import { logger } from "../utils/logger";
// 비용 유형 타입
export type CostType = "purchase" | "installation" | "repair" | "maintenance" | "disposal" | "other";
// 세금계산서 타입 정의
export interface TaxInvoice {
id: string;
company_code: string;
invoice_number: string;
invoice_type: "sales" | "purchase"; // 매출/매입
invoice_status: "draft" | "issued" | "sent" | "cancelled";
// 공급자 정보
supplier_business_no: string;
supplier_name: string;
supplier_ceo_name: string;
supplier_address: string;
supplier_business_type: string;
supplier_business_item: string;
// 공급받는자 정보
buyer_business_no: string;
buyer_name: string;
buyer_ceo_name: string;
buyer_address: string;
buyer_email: string;
// 금액 정보
supply_amount: number;
tax_amount: number;
total_amount: number;
// 날짜 정보
invoice_date: string;
issue_date: string | null;
// 기타
remarks: string;
order_id: string | null;
customer_id: string | null;
// 첨부파일 (JSON 배열로 저장)
attachments: TaxInvoiceAttachment[] | null;
// 비용 유형 (구매/설치/수리/유지보수/폐기/기타)
cost_type: CostType | null;
created_date: string;
updated_date: string;
writer: string;
}
// 첨부파일 타입
export interface TaxInvoiceAttachment {
id: string;
file_name: string;
file_path: string;
file_size: number;
file_type: string;
uploaded_at: string;
uploaded_by: string;
}
export interface TaxInvoiceItem {
id: string;
tax_invoice_id: string;
company_code: string;
item_seq: number;
item_date: string;
item_name: string;
item_spec: string;
quantity: number;
unit_price: number;
supply_amount: number;
tax_amount: number;
remarks: string;
}
export interface CreateTaxInvoiceDto {
invoice_type: "sales" | "purchase";
supplier_business_no?: string;
supplier_name?: string;
supplier_ceo_name?: string;
supplier_address?: string;
supplier_business_type?: string;
supplier_business_item?: string;
buyer_business_no?: string;
buyer_name?: string;
buyer_ceo_name?: string;
buyer_address?: string;
buyer_email?: string;
supply_amount: number;
tax_amount: number;
total_amount: number;
invoice_date: string;
remarks?: string;
order_id?: string;
customer_id?: string;
items?: CreateTaxInvoiceItemDto[];
attachments?: TaxInvoiceAttachment[]; // 첨부파일
cost_type?: CostType; // 비용 유형
}
export interface CreateTaxInvoiceItemDto {
item_date?: string;
item_name: string;
item_spec?: string;
quantity: number;
unit_price: number;
supply_amount: number;
tax_amount: number;
remarks?: string;
}
export interface TaxInvoiceListParams {
page?: number;
pageSize?: number;
invoice_type?: "sales" | "purchase";
invoice_status?: string;
start_date?: string;
end_date?: string;
search?: string;
buyer_name?: string;
cost_type?: CostType; // 비용 유형 필터
}
export class TaxInvoiceService {
/**
* 세금계산서 번호 채번
* 형식: YYYYMM-NNNNN (예: 202512-00001)
*/
static async generateInvoiceNumber(companyCode: string): Promise<string> {
const now = new Date();
const yearMonth = `${now.getFullYear()}${String(now.getMonth() + 1).padStart(2, "0")}`;
const prefix = `${yearMonth}-`;
// 해당 월의 마지막 번호 조회
const result = await query<{ max_num: string }>(
`SELECT invoice_number as max_num
FROM tax_invoice
WHERE company_code = $1
AND invoice_number LIKE $2
ORDER BY invoice_number DESC
LIMIT 1`,
[companyCode, `${prefix}%`]
);
let nextNum = 1;
if (result.length > 0 && result[0].max_num) {
const lastNum = parseInt(result[0].max_num.split("-")[1], 10);
nextNum = lastNum + 1;
}
return `${prefix}${String(nextNum).padStart(5, "0")}`;
}
/**
* 세금계산서 목록 조회
*/
static async getList(
companyCode: string,
params: TaxInvoiceListParams
): Promise<{ data: TaxInvoice[]; total: number; page: number; pageSize: number }> {
const {
page = 1,
pageSize = 20,
invoice_type,
invoice_status,
start_date,
end_date,
search,
buyer_name,
cost_type,
} = params;
const offset = (page - 1) * pageSize;
const conditions: string[] = ["company_code = $1"];
const values: any[] = [companyCode];
let paramIndex = 2;
if (invoice_type) {
conditions.push(`invoice_type = $${paramIndex}`);
values.push(invoice_type);
paramIndex++;
}
if (invoice_status) {
conditions.push(`invoice_status = $${paramIndex}`);
values.push(invoice_status);
paramIndex++;
}
if (start_date) {
conditions.push(`invoice_date >= $${paramIndex}`);
values.push(start_date);
paramIndex++;
}
if (end_date) {
conditions.push(`invoice_date <= $${paramIndex}`);
values.push(end_date);
paramIndex++;
}
if (search) {
conditions.push(
`(invoice_number ILIKE $${paramIndex} OR buyer_name ILIKE $${paramIndex} OR supplier_name ILIKE $${paramIndex})`
);
values.push(`%${search}%`);
paramIndex++;
}
if (buyer_name) {
conditions.push(`buyer_name ILIKE $${paramIndex}`);
values.push(`%${buyer_name}%`);
paramIndex++;
}
if (cost_type) {
conditions.push(`cost_type = $${paramIndex}`);
values.push(cost_type);
paramIndex++;
}
const whereClause = conditions.join(" AND ");
// 전체 개수 조회
const countResult = await query<{ count: string }>(
`SELECT COUNT(*) as count FROM tax_invoice WHERE ${whereClause}`,
values
);
const total = parseInt(countResult[0]?.count || "0", 10);
// 데이터 조회
values.push(pageSize, offset);
const data = await query<TaxInvoice>(
`SELECT * FROM tax_invoice
WHERE ${whereClause}
ORDER BY created_date DESC
LIMIT $${paramIndex} OFFSET $${paramIndex + 1}`,
values
);
return { data, total, page, pageSize };
}
/**
* 세금계산서 상세 조회 (품목 포함)
*/
static async getById(
id: string,
companyCode: string
): Promise<{ invoice: TaxInvoice; items: TaxInvoiceItem[] } | null> {
const invoiceResult = await query<TaxInvoice>(
`SELECT * FROM tax_invoice WHERE id = $1 AND company_code = $2`,
[id, companyCode]
);
if (invoiceResult.length === 0) {
return null;
}
const items = await query<TaxInvoiceItem>(
`SELECT * FROM tax_invoice_item
WHERE tax_invoice_id = $1 AND company_code = $2
ORDER BY item_seq`,
[id, companyCode]
);
return { invoice: invoiceResult[0], items };
}
/**
* 세금계산서 생성
*/
static async create(
data: CreateTaxInvoiceDto,
companyCode: string,
userId: string
): Promise<TaxInvoice> {
return await transaction(async (client) => {
// 세금계산서 번호 채번
const invoiceNumber = await this.generateInvoiceNumber(companyCode);
// 세금계산서 생성
const invoiceResult = await client.query(
`INSERT INTO tax_invoice (
company_code, invoice_number, invoice_type, invoice_status,
supplier_business_no, supplier_name, supplier_ceo_name, supplier_address,
supplier_business_type, supplier_business_item,
buyer_business_no, buyer_name, buyer_ceo_name, buyer_address, buyer_email,
supply_amount, tax_amount, total_amount, invoice_date,
remarks, order_id, customer_id, attachments, cost_type, writer
) VALUES (
$1, $2, $3, 'draft',
$4, $5, $6, $7, $8, $9,
$10, $11, $12, $13, $14,
$15, $16, $17, $18,
$19, $20, $21, $22, $23, $24
) RETURNING *`,
[
companyCode,
invoiceNumber,
data.invoice_type,
data.supplier_business_no || null,
data.supplier_name || null,
data.supplier_ceo_name || null,
data.supplier_address || null,
data.supplier_business_type || null,
data.supplier_business_item || null,
data.buyer_business_no || null,
data.buyer_name || null,
data.buyer_ceo_name || null,
data.buyer_address || null,
data.buyer_email || null,
data.supply_amount,
data.tax_amount,
data.total_amount,
data.invoice_date,
data.remarks || null,
data.order_id || null,
data.customer_id || null,
data.attachments ? JSON.stringify(data.attachments) : null,
data.cost_type || null,
userId,
]
);
const invoice = invoiceResult.rows[0];
// 품목 생성
if (data.items && data.items.length > 0) {
for (let i = 0; i < data.items.length; i++) {
const item = data.items[i];
await client.query(
`INSERT INTO tax_invoice_item (
tax_invoice_id, company_code, item_seq,
item_date, item_name, item_spec, quantity, unit_price,
supply_amount, tax_amount, remarks
) VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11)`,
[
invoice.id,
companyCode,
i + 1,
item.item_date || null,
item.item_name,
item.item_spec || null,
item.quantity,
item.unit_price,
item.supply_amount,
item.tax_amount,
item.remarks || null,
]
);
}
}
logger.info("세금계산서 생성 완료", {
invoiceId: invoice.id,
invoiceNumber,
companyCode,
userId,
});
return invoice;
});
}
/**
* 세금계산서 수정
*/
static async update(
id: string,
data: Partial<CreateTaxInvoiceDto>,
companyCode: string,
userId: string
): Promise<TaxInvoice | null> {
return await transaction(async (client) => {
// 기존 세금계산서 확인
const existing = await client.query(
`SELECT * FROM tax_invoice WHERE id = $1 AND company_code = $2`,
[id, companyCode]
);
if (existing.rows.length === 0) {
return null;
}
// 발행된 세금계산서는 수정 불가
if (existing.rows[0].invoice_status !== "draft") {
throw new Error("발행된 세금계산서는 수정할 수 없습니다.");
}
// 세금계산서 수정
const updateResult = await client.query(
`UPDATE tax_invoice SET
supplier_business_no = COALESCE($3, supplier_business_no),
supplier_name = COALESCE($4, supplier_name),
supplier_ceo_name = COALESCE($5, supplier_ceo_name),
supplier_address = COALESCE($6, supplier_address),
supplier_business_type = COALESCE($7, supplier_business_type),
supplier_business_item = COALESCE($8, supplier_business_item),
buyer_business_no = COALESCE($9, buyer_business_no),
buyer_name = COALESCE($10, buyer_name),
buyer_ceo_name = COALESCE($11, buyer_ceo_name),
buyer_address = COALESCE($12, buyer_address),
buyer_email = COALESCE($13, buyer_email),
supply_amount = COALESCE($14, supply_amount),
tax_amount = COALESCE($15, tax_amount),
total_amount = COALESCE($16, total_amount),
invoice_date = COALESCE($17, invoice_date),
remarks = COALESCE($18, remarks),
attachments = $19,
cost_type = COALESCE($20, cost_type),
updated_date = NOW()
WHERE id = $1 AND company_code = $2
RETURNING *`,
[
id,
companyCode,
data.supplier_business_no,
data.supplier_name,
data.supplier_ceo_name,
data.supplier_address,
data.supplier_business_type,
data.supplier_business_item,
data.buyer_business_no,
data.buyer_name,
data.buyer_ceo_name,
data.buyer_address,
data.buyer_email,
data.supply_amount,
data.tax_amount,
data.total_amount,
data.invoice_date,
data.remarks,
data.attachments ? JSON.stringify(data.attachments) : null,
data.cost_type,
]
);
// 품목 업데이트 (기존 삭제 후 재생성)
if (data.items) {
await client.query(
`DELETE FROM tax_invoice_item WHERE tax_invoice_id = $1 AND company_code = $2`,
[id, companyCode]
);
for (let i = 0; i < data.items.length; i++) {
const item = data.items[i];
await client.query(
`INSERT INTO tax_invoice_item (
tax_invoice_id, company_code, item_seq,
item_date, item_name, item_spec, quantity, unit_price,
supply_amount, tax_amount, remarks
) VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11)`,
[
id,
companyCode,
i + 1,
item.item_date || null,
item.item_name,
item.item_spec || null,
item.quantity,
item.unit_price,
item.supply_amount,
item.tax_amount,
item.remarks || null,
]
);
}
}
logger.info("세금계산서 수정 완료", { invoiceId: id, companyCode, userId });
return updateResult.rows[0];
});
}
/**
* 세금계산서 삭제
*/
static async delete(id: string, companyCode: string, userId: string): Promise<boolean> {
return await transaction(async (client) => {
// 기존 세금계산서 확인
const existing = await client.query(
`SELECT * FROM tax_invoice WHERE id = $1 AND company_code = $2`,
[id, companyCode]
);
if (existing.rows.length === 0) {
return false;
}
// 발행된 세금계산서는 삭제 불가
if (existing.rows[0].invoice_status !== "draft") {
throw new Error("발행된 세금계산서는 삭제할 수 없습니다.");
}
// 품목 삭제
await client.query(
`DELETE FROM tax_invoice_item WHERE tax_invoice_id = $1 AND company_code = $2`,
[id, companyCode]
);
// 세금계산서 삭제
await client.query(`DELETE FROM tax_invoice WHERE id = $1 AND company_code = $2`, [
id,
companyCode,
]);
logger.info("세금계산서 삭제 완료", { invoiceId: id, companyCode, userId });
return true;
});
}
/**
* 세금계산서 발행 (상태 변경)
*/
static async issue(id: string, companyCode: string, userId: string): Promise<TaxInvoice | null> {
const result = await query<TaxInvoice>(
`UPDATE tax_invoice SET
invoice_status = 'issued',
issue_date = NOW(),
updated_date = NOW()
WHERE id = $1 AND company_code = $2 AND invoice_status = 'draft'
RETURNING *`,
[id, companyCode]
);
if (result.length === 0) {
return null;
}
logger.info("세금계산서 발행 완료", { invoiceId: id, companyCode, userId });
return result[0];
}
/**
* 세금계산서 취소
*/
static async cancel(
id: string,
companyCode: string,
userId: string,
reason?: string
): Promise<TaxInvoice | null> {
const result = await query<TaxInvoice>(
`UPDATE tax_invoice SET
invoice_status = 'cancelled',
remarks = CASE WHEN $3 IS NOT NULL THEN remarks || ' [취소사유: ' || $3 || ']' ELSE remarks END,
updated_date = NOW()
WHERE id = $1 AND company_code = $2 AND invoice_status IN ('draft', 'issued')
RETURNING *`,
[id, companyCode, reason || null]
);
if (result.length === 0) {
return null;
}
logger.info("세금계산서 취소 완료", { invoiceId: id, companyCode, userId, reason });
return result[0];
}
/**
* 월별 통계 조회
*/
static async getMonthlyStats(
companyCode: string,
year: number,
month: number
): Promise<{
sales: { count: number; supply_amount: number; tax_amount: number; total_amount: number };
purchase: { count: number; supply_amount: number; tax_amount: number; total_amount: number };
}> {
const startDate = `${year}-${String(month).padStart(2, "0")}-01`;
const endDate = new Date(year, month, 0).toISOString().split("T")[0]; // 해당 월 마지막 날
const result = await query<{
invoice_type: string;
count: string;
supply_amount: string;
tax_amount: string;
total_amount: string;
}>(
`SELECT
invoice_type,
COUNT(*) as count,
COALESCE(SUM(supply_amount), 0) as supply_amount,
COALESCE(SUM(tax_amount), 0) as tax_amount,
COALESCE(SUM(total_amount), 0) as total_amount
FROM tax_invoice
WHERE company_code = $1
AND invoice_date >= $2
AND invoice_date <= $3
AND invoice_status != 'cancelled'
GROUP BY invoice_type`,
[companyCode, startDate, endDate]
);
const stats = {
sales: { count: 0, supply_amount: 0, tax_amount: 0, total_amount: 0 },
purchase: { count: 0, supply_amount: 0, tax_amount: 0, total_amount: 0 },
};
for (const row of result) {
const type = row.invoice_type as "sales" | "purchase";
stats[type] = {
count: parseInt(row.count, 10),
supply_amount: parseFloat(row.supply_amount),
tax_amount: parseFloat(row.tax_amount),
total_amount: parseFloat(row.total_amount),
};
}
return stats;
}
/**
* 비용 유형별 통계 조회
*/
static async getCostTypeStats(
companyCode: string,
year?: number,
month?: number
): Promise<{
by_cost_type: Array<{
cost_type: CostType | null;
count: number;
supply_amount: number;
tax_amount: number;
total_amount: number;
}>;
by_month: Array<{
year_month: string;
cost_type: CostType | null;
count: number;
total_amount: number;
}>;
summary: {
total_count: number;
total_amount: number;
purchase_amount: number;
installation_amount: number;
repair_amount: number;
maintenance_amount: number;
disposal_amount: number;
other_amount: number;
};
}> {
const conditions: string[] = ["company_code = $1", "invoice_status != 'cancelled'"];
const values: any[] = [companyCode];
let paramIndex = 2;
// 연도/월 필터
if (year && month) {
const startDate = `${year}-${String(month).padStart(2, "0")}-01`;
const endDate = new Date(year, month, 0).toISOString().split("T")[0];
conditions.push(`invoice_date >= $${paramIndex} AND invoice_date <= $${paramIndex + 1}`);
values.push(startDate, endDate);
paramIndex += 2;
} else if (year) {
conditions.push(`EXTRACT(YEAR FROM invoice_date) = $${paramIndex}`);
values.push(year);
paramIndex++;
}
const whereClause = conditions.join(" AND ");
// 비용 유형별 집계
const byCostType = await query<{
cost_type: CostType | null;
count: string;
supply_amount: string;
tax_amount: string;
total_amount: string;
}>(
`SELECT
cost_type,
COUNT(*) as count,
COALESCE(SUM(supply_amount), 0) as supply_amount,
COALESCE(SUM(tax_amount), 0) as tax_amount,
COALESCE(SUM(total_amount), 0) as total_amount
FROM tax_invoice
WHERE ${whereClause}
GROUP BY cost_type
ORDER BY total_amount DESC`,
values
);
// 월별 비용 유형 집계
const byMonth = await query<{
year_month: string;
cost_type: CostType | null;
count: string;
total_amount: string;
}>(
`SELECT
TO_CHAR(invoice_date, 'YYYY-MM') as year_month,
cost_type,
COUNT(*) as count,
COALESCE(SUM(total_amount), 0) as total_amount
FROM tax_invoice
WHERE ${whereClause}
GROUP BY TO_CHAR(invoice_date, 'YYYY-MM'), cost_type
ORDER BY year_month DESC, cost_type`,
values
);
// 전체 요약
const summaryResult = await query<{
total_count: string;
total_amount: string;
purchase_amount: string;
installation_amount: string;
repair_amount: string;
maintenance_amount: string;
disposal_amount: string;
other_amount: string;
}>(
`SELECT
COUNT(*) as total_count,
COALESCE(SUM(total_amount), 0) as total_amount,
COALESCE(SUM(CASE WHEN cost_type = 'purchase' THEN total_amount ELSE 0 END), 0) as purchase_amount,
COALESCE(SUM(CASE WHEN cost_type = 'installation' THEN total_amount ELSE 0 END), 0) as installation_amount,
COALESCE(SUM(CASE WHEN cost_type = 'repair' THEN total_amount ELSE 0 END), 0) as repair_amount,
COALESCE(SUM(CASE WHEN cost_type = 'maintenance' THEN total_amount ELSE 0 END), 0) as maintenance_amount,
COALESCE(SUM(CASE WHEN cost_type = 'disposal' THEN total_amount ELSE 0 END), 0) as disposal_amount,
COALESCE(SUM(CASE WHEN cost_type = 'other' THEN total_amount ELSE 0 END), 0) as other_amount
FROM tax_invoice
WHERE ${whereClause}`,
values
);
const summary = summaryResult[0] || {
total_count: "0",
total_amount: "0",
purchase_amount: "0",
installation_amount: "0",
repair_amount: "0",
maintenance_amount: "0",
disposal_amount: "0",
other_amount: "0",
};
return {
by_cost_type: byCostType.map((row) => ({
cost_type: row.cost_type,
count: parseInt(row.count, 10),
supply_amount: parseFloat(row.supply_amount),
tax_amount: parseFloat(row.tax_amount),
total_amount: parseFloat(row.total_amount),
})),
by_month: byMonth.map((row) => ({
year_month: row.year_month,
cost_type: row.cost_type,
count: parseInt(row.count, 10),
total_amount: parseFloat(row.total_amount),
})),
summary: {
total_count: parseInt(summary.total_count, 10),
total_amount: parseFloat(summary.total_amount),
purchase_amount: parseFloat(summary.purchase_amount),
installation_amount: parseFloat(summary.installation_amount),
repair_amount: parseFloat(summary.repair_amount),
maintenance_amount: parseFloat(summary.maintenance_amount),
disposal_amount: parseFloat(summary.disposal_amount),
other_amount: parseFloat(summary.other_amount),
},
};
}
}