903 lines
24 KiB
JavaScript
903 lines
24 KiB
JavaScript
#!/usr/bin/env node
|
|
/* eslint-disable @typescript-eslint/no-var-requires, @typescript-eslint/no-require-imports, unicorn/prefer-module, n/prefer-global/process, no-console */
|
|
const fs = require('node:fs');
|
|
const path = require('node:path');
|
|
|
|
const { Pool } = require('pg');
|
|
|
|
const DEFAULT_PG_HOST = process.env.POSTGRES_HOST ?? 'localhost';
|
|
const DEFAULT_PG_PORT = Number.parseInt(
|
|
process.env.POSTGRES_PORT ?? '5432',
|
|
10,
|
|
);
|
|
const DEFAULT_PG_DB = process.env.POSTGRES_DB ?? 'kt_financial';
|
|
const DEFAULT_PG_USER = process.env.POSTGRES_USER ?? 'kt_financial';
|
|
const DEFAULT_PG_PASSWORD = process.env.POSTGRES_PASSWORD ?? 'kt_financial_pwd';
|
|
|
|
const DEFAULT_CONNECTION_STRING =
|
|
process.env.POSTGRES_URL ??
|
|
`postgresql://${DEFAULT_PG_USER}:${DEFAULT_PG_PASSWORD}@${DEFAULT_PG_HOST}:${DEFAULT_PG_PORT}/${DEFAULT_PG_DB}`;
|
|
|
|
const NEW_HEADER_KEYS = {
|
|
date: '日期',
|
|
type: '类型',
|
|
category: '分类',
|
|
project: '项目名称',
|
|
amount: '金额',
|
|
currency: '币种',
|
|
account: '账户',
|
|
};
|
|
|
|
const LEGACY_BASE_CURRENCIES = [
|
|
{ code: 'CNY', name: '人民币', symbol: '¥', isBase: true },
|
|
{ code: 'USD', name: '美元', symbol: '$', isBase: false },
|
|
{ code: 'THB', name: '泰铢', symbol: '฿', isBase: false },
|
|
];
|
|
|
|
const LEGACY_BASE_EXCHANGE_RATES = [
|
|
{
|
|
fromCurrency: 'CNY',
|
|
toCurrency: 'CNY',
|
|
rate: 1,
|
|
date: '2025-01-01',
|
|
source: 'system',
|
|
},
|
|
{
|
|
fromCurrency: 'USD',
|
|
toCurrency: 'CNY',
|
|
rate: 7.14,
|
|
date: '2025-01-01',
|
|
source: 'manual',
|
|
},
|
|
{
|
|
fromCurrency: 'THB',
|
|
toCurrency: 'CNY',
|
|
rate: 0.2,
|
|
date: '2025-01-01',
|
|
source: 'manual',
|
|
},
|
|
];
|
|
|
|
function parseArgs(argv) {
|
|
const params = {};
|
|
for (let i = 0; i < argv.length; i += 1) {
|
|
const arg = argv[i];
|
|
if (!arg.startsWith('--')) {
|
|
continue;
|
|
}
|
|
const key = arg.slice(2);
|
|
const next = argv[i + 1];
|
|
if (!next || next.startsWith('--')) {
|
|
params[key] = true;
|
|
} else {
|
|
params[key] = next;
|
|
i += 1;
|
|
}
|
|
}
|
|
return params;
|
|
}
|
|
|
|
function splitCsvRow(row) {
|
|
const result = [];
|
|
let current = '';
|
|
let inQuotes = false;
|
|
for (let i = 0; i < row.length; i += 1) {
|
|
const char = row[i];
|
|
if (char === '"') {
|
|
if (inQuotes && row[i + 1] === '"') {
|
|
current += '"';
|
|
i += 1;
|
|
} else {
|
|
inQuotes = !inQuotes;
|
|
}
|
|
} else if (char === ',' && !inQuotes) {
|
|
result.push(current.trim());
|
|
current = '';
|
|
} else {
|
|
current += char;
|
|
}
|
|
}
|
|
result.push(current.trim());
|
|
return result;
|
|
}
|
|
|
|
function parseCsv(content) {
|
|
const sanitized = content.replace(/^\uFEFF/, '');
|
|
const lines = sanitized
|
|
.split(/\r?\n/)
|
|
.map((line) => line.trim())
|
|
.filter((line) => line.length > 0);
|
|
|
|
if (lines.length <= 1) {
|
|
return { header: [], rows: [] };
|
|
}
|
|
|
|
const header = splitCsvRow(lines[0]);
|
|
const rows = lines.slice(1).map((line) => splitCsvRow(line));
|
|
return { header, rows };
|
|
}
|
|
|
|
function parseCategoryWithIcon(raw) {
|
|
if (!raw) {
|
|
return { icon: '📝', name: '未分类' };
|
|
}
|
|
const trimmed = raw.trim();
|
|
const parts = trimmed.split(/\s+/);
|
|
if (parts.length > 1 && /\p{Emoji}/u.test(parts[0])) {
|
|
return { icon: parts[0], name: parts.slice(1).join(' ') };
|
|
}
|
|
return { icon: '📝', name: trimmed };
|
|
}
|
|
|
|
function inferCurrency(accountName, amountText) {
|
|
const text = `${accountName ?? ''}${amountText ?? ''}`.toLowerCase();
|
|
if (
|
|
text.includes('美金') ||
|
|
text.includes('usd') ||
|
|
text.includes('u$') ||
|
|
text.includes('u ')
|
|
) {
|
|
return 'USD';
|
|
}
|
|
if (text.includes('泰铢') || text.includes('thb')) {
|
|
return 'THB';
|
|
}
|
|
return 'CNY';
|
|
}
|
|
|
|
function parseAmount(raw) {
|
|
if (!raw) return 0;
|
|
const matches = String(raw)
|
|
.replaceAll(/[^0-9.+-]/g, (char) =>
|
|
char === '+' || char === '-' ? char : ' ',
|
|
)
|
|
.match(/[-+]?\d+(?:\.\d+)?/g);
|
|
if (!matches) return 0;
|
|
return matches.map(Number).reduce((sum, value) => sum + value, 0);
|
|
}
|
|
|
|
function resolveTransactionType(raw) {
|
|
if (!raw) {
|
|
return 'expense';
|
|
}
|
|
const text = raw.trim();
|
|
if (text.includes('收') || text.includes('入')) {
|
|
return 'income';
|
|
}
|
|
return 'expense';
|
|
}
|
|
|
|
function resolveCurrencySymbol(code) {
|
|
if (code === 'CNY') return '¥';
|
|
if (code === 'USD') return '$';
|
|
return code;
|
|
}
|
|
|
|
function resolveCurrencyIcon(code) {
|
|
if (code === 'USD') return '💵';
|
|
if (code === 'THB') return '💱';
|
|
return '💰';
|
|
}
|
|
|
|
function resolveCurrencyColor(code) {
|
|
if (code === 'USD') return '#1677ff';
|
|
if (code === 'THB') return '#22c55e';
|
|
if (code === 'CNY') return '#6366f1';
|
|
return '#6366f1';
|
|
}
|
|
|
|
function normalizeDate(rawValue, monthTracker, baseYear) {
|
|
const value = rawValue.trim();
|
|
|
|
if (/^\d{4}-\d{2}-\d{2}$/.test(value)) {
|
|
const month = Number(value.slice(5, 7));
|
|
monthTracker.lastMonth = month;
|
|
return value;
|
|
}
|
|
|
|
if (/^\d{8}$/.test(value)) {
|
|
const year = value.slice(0, 4);
|
|
const monthText = value.slice(4, 6);
|
|
const dayText = value.slice(6, 8);
|
|
monthTracker.lastMonth = Number(monthText);
|
|
return `${year}-${monthText}-${dayText}`;
|
|
}
|
|
|
|
const match = value.match(/(\d{1,2})月(\d{1,2})日/);
|
|
if (!match) {
|
|
throw new Error(`无法解析日期: ${value}`);
|
|
}
|
|
const month = Number(match[1]);
|
|
const day = Number(match[2]);
|
|
let year = baseYear;
|
|
if (
|
|
monthTracker.lastMonth !== null &&
|
|
month > monthTracker.lastMonth &&
|
|
monthTracker.wrapped
|
|
) {
|
|
year -= 1;
|
|
}
|
|
if (
|
|
monthTracker.lastMonth !== null &&
|
|
month < monthTracker.lastMonth &&
|
|
!monthTracker.wrapped
|
|
) {
|
|
monthTracker.wrapped = true;
|
|
}
|
|
monthTracker.lastMonth = month;
|
|
const mm = String(month).padStart(2, '0');
|
|
const dd = String(day).padStart(2, '0');
|
|
return `${year}-${mm}-${dd}`;
|
|
}
|
|
|
|
async function resetFinanceTables(client) {
|
|
await ensureSchema(client);
|
|
await client.query(`
|
|
TRUNCATE TABLE
|
|
finance_transactions,
|
|
finance_accounts,
|
|
finance_categories,
|
|
finance_exchange_rates,
|
|
finance_currencies
|
|
RESTART IDENTITY CASCADE
|
|
`);
|
|
}
|
|
|
|
async function ensureCurrency(client, cache, code, name = code, symbol = code) {
|
|
if (cache.currencies.has(code)) {
|
|
return;
|
|
}
|
|
await client.query(
|
|
`INSERT INTO finance_currencies (code, name, symbol, is_base, is_active)
|
|
VALUES ($1, $2, $3, $4, TRUE)
|
|
ON CONFLICT (code) DO UPDATE
|
|
SET name = EXCLUDED.name,
|
|
symbol = EXCLUDED.symbol,
|
|
is_active = TRUE`,
|
|
[code, name, symbol, code === 'CNY'],
|
|
);
|
|
cache.currencies.add(code);
|
|
}
|
|
|
|
async function ensureSchema(client) {
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS finance_currencies (
|
|
code TEXT PRIMARY KEY,
|
|
name TEXT NOT NULL,
|
|
symbol TEXT NOT NULL,
|
|
is_base BOOLEAN NOT NULL DEFAULT FALSE,
|
|
is_active BOOLEAN NOT NULL DEFAULT TRUE
|
|
);
|
|
`);
|
|
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS finance_exchange_rates (
|
|
id SERIAL PRIMARY KEY,
|
|
from_currency TEXT NOT NULL REFERENCES finance_currencies(code),
|
|
to_currency TEXT NOT NULL REFERENCES finance_currencies(code),
|
|
rate NUMERIC NOT NULL,
|
|
date DATE NOT NULL,
|
|
source TEXT DEFAULT 'manual'
|
|
);
|
|
`);
|
|
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS finance_accounts (
|
|
id SERIAL PRIMARY KEY,
|
|
name TEXT NOT NULL,
|
|
currency TEXT NOT NULL REFERENCES finance_currencies(code),
|
|
type TEXT DEFAULT 'cash',
|
|
icon TEXT,
|
|
color TEXT,
|
|
user_id INTEGER DEFAULT 1,
|
|
is_active BOOLEAN DEFAULT TRUE
|
|
);
|
|
`);
|
|
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS finance_categories (
|
|
id SERIAL PRIMARY KEY,
|
|
name TEXT NOT NULL,
|
|
type TEXT NOT NULL,
|
|
icon TEXT,
|
|
color TEXT,
|
|
user_id INTEGER,
|
|
is_active BOOLEAN DEFAULT TRUE
|
|
);
|
|
`);
|
|
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS finance_transactions (
|
|
id SERIAL PRIMARY KEY,
|
|
type TEXT NOT NULL,
|
|
amount NUMERIC NOT NULL,
|
|
currency TEXT NOT NULL REFERENCES finance_currencies(code),
|
|
exchange_rate_to_base NUMERIC NOT NULL,
|
|
amount_in_base NUMERIC NOT NULL,
|
|
category_id INTEGER REFERENCES finance_categories(id),
|
|
account_id INTEGER REFERENCES finance_accounts(id),
|
|
transaction_date DATE NOT NULL,
|
|
description TEXT,
|
|
project TEXT,
|
|
memo TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
status TEXT NOT NULL DEFAULT 'approved',
|
|
status_updated_at TIMESTAMP WITH TIME ZONE,
|
|
reimbursement_batch TEXT,
|
|
review_notes TEXT,
|
|
submitted_by TEXT,
|
|
approved_by TEXT,
|
|
approved_at TIMESTAMP WITH TIME ZONE,
|
|
is_deleted BOOLEAN NOT NULL DEFAULT FALSE,
|
|
deleted_at TIMESTAMP WITH TIME ZONE
|
|
);
|
|
`);
|
|
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS finance_media_messages (
|
|
id SERIAL PRIMARY KEY,
|
|
chat_id BIGINT NOT NULL,
|
|
message_id BIGINT NOT NULL,
|
|
user_id INTEGER NOT NULL,
|
|
username TEXT,
|
|
display_name TEXT,
|
|
file_type TEXT NOT NULL,
|
|
file_id TEXT NOT NULL,
|
|
file_unique_id TEXT,
|
|
caption TEXT,
|
|
file_name TEXT,
|
|
file_path TEXT NOT NULL,
|
|
file_size INTEGER,
|
|
mime_type TEXT,
|
|
duration INTEGER,
|
|
width INTEGER,
|
|
height INTEGER,
|
|
forwarded_to INTEGER,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
UNIQUE(chat_id, message_id)
|
|
);
|
|
`);
|
|
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS telegram_notification_configs (
|
|
id SERIAL PRIMARY KEY,
|
|
name TEXT NOT NULL,
|
|
bot_token TEXT NOT NULL,
|
|
chat_id TEXT NOT NULL,
|
|
notification_types TEXT NOT NULL,
|
|
is_enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
|
priority TEXT DEFAULT 'normal',
|
|
rate_limit_seconds INTEGER DEFAULT 0,
|
|
batch_enabled BOOLEAN DEFAULT FALSE,
|
|
batch_interval_minutes INTEGER DEFAULT 60,
|
|
retry_enabled BOOLEAN DEFAULT TRUE,
|
|
retry_max_attempts INTEGER DEFAULT 3,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
|
|
);
|
|
`);
|
|
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS telegram_notification_history (
|
|
id SERIAL PRIMARY KEY,
|
|
config_id INTEGER NOT NULL REFERENCES telegram_notification_configs(id),
|
|
notification_type TEXT NOT NULL,
|
|
content_hash TEXT NOT NULL,
|
|
status TEXT NOT NULL DEFAULT 'pending',
|
|
retry_count INTEGER DEFAULT 0,
|
|
sent_at TIMESTAMP WITH TIME ZONE,
|
|
error_message TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
|
|
);
|
|
`);
|
|
|
|
await client.query(`
|
|
CREATE INDEX IF NOT EXISTS idx_finance_media_messages_created_at
|
|
ON finance_media_messages (created_at DESC);
|
|
`);
|
|
await client.query(`
|
|
CREATE INDEX IF NOT EXISTS idx_finance_media_messages_user_id
|
|
ON finance_media_messages (user_id);
|
|
`);
|
|
await client.query(`
|
|
CREATE INDEX IF NOT EXISTS idx_telegram_notification_configs_enabled
|
|
ON telegram_notification_configs (is_enabled);
|
|
`);
|
|
await client.query(`
|
|
CREATE INDEX IF NOT EXISTS idx_telegram_notification_history_config
|
|
ON telegram_notification_history (config_id, created_at DESC);
|
|
`);
|
|
await client.query(`
|
|
CREATE INDEX IF NOT EXISTS idx_telegram_notification_history_hash
|
|
ON telegram_notification_history (content_hash, created_at DESC);
|
|
`);
|
|
await client.query(`
|
|
CREATE INDEX IF NOT EXISTS idx_telegram_notification_history_status
|
|
ON telegram_notification_history (status, retry_count);
|
|
`);
|
|
}
|
|
|
|
async function ensureExchangeRate(
|
|
client,
|
|
cache,
|
|
fromCurrency,
|
|
toCurrency,
|
|
rate = 1,
|
|
date = '1970-01-01',
|
|
source = 'import-script',
|
|
) {
|
|
const key = `${fromCurrency}->${toCurrency}`;
|
|
if (cache.exchangeRates.has(key)) {
|
|
return cache.exchangeRates.get(key);
|
|
}
|
|
const { rows } = await client.query(
|
|
`SELECT rate
|
|
FROM finance_exchange_rates
|
|
WHERE from_currency = $1 AND to_currency = $2
|
|
ORDER BY date DESC
|
|
LIMIT 1`,
|
|
[fromCurrency, toCurrency],
|
|
);
|
|
if (!rows[0]) {
|
|
await client.query(
|
|
`INSERT INTO finance_exchange_rates (from_currency, to_currency, rate, date, source)
|
|
VALUES ($1, $2, $3, $4, $5)`,
|
|
[fromCurrency, toCurrency, rate, date, source],
|
|
);
|
|
cache.exchangeRates.set(key, rate);
|
|
return rate;
|
|
}
|
|
const dbRate = Number(rows[0].rate) || rate;
|
|
cache.exchangeRates.set(key, dbRate);
|
|
return dbRate;
|
|
}
|
|
|
|
async function ensureAccount(
|
|
client,
|
|
cache,
|
|
{ name, currency, type = 'cash', icon = '💼', color = '#1677ff', userId = 1 },
|
|
) {
|
|
const key = `${name}::${currency}`;
|
|
if (cache.accounts.has(key)) {
|
|
return cache.accounts.get(key);
|
|
}
|
|
const { rows } = await client.query(
|
|
`SELECT id
|
|
FROM finance_accounts
|
|
WHERE name = $1
|
|
LIMIT 1`,
|
|
[name],
|
|
);
|
|
if (rows[0]) {
|
|
const existingId = Number(rows[0].id);
|
|
cache.accounts.set(key, existingId);
|
|
return existingId;
|
|
}
|
|
const result = await client.query(
|
|
`INSERT INTO finance_accounts (name, currency, type, icon, color, user_id, is_active)
|
|
VALUES ($1, $2, $3, $4, $5, $6, TRUE)
|
|
RETURNING id`,
|
|
[name, currency, type, icon, color, userId],
|
|
);
|
|
const createdId = Number(result.rows[0].id);
|
|
cache.accounts.set(key, createdId);
|
|
return createdId;
|
|
}
|
|
|
|
async function ensureCategory(
|
|
client,
|
|
cache,
|
|
{ name, type, icon = '📝', color = '#dfe4ea', userId = 1 },
|
|
) {
|
|
const key = `${type}:${name}`;
|
|
if (cache.categories.has(key)) {
|
|
return cache.categories.get(key);
|
|
}
|
|
const { rows } = await client.query(
|
|
`SELECT id
|
|
FROM finance_categories
|
|
WHERE name = $1 AND type = $2
|
|
LIMIT 1`,
|
|
[name, type],
|
|
);
|
|
if (rows[0]) {
|
|
const existingId = Number(rows[0].id);
|
|
cache.categories.set(key, existingId);
|
|
return existingId;
|
|
}
|
|
const result = await client.query(
|
|
`INSERT INTO finance_categories (name, type, icon, color, user_id, is_active)
|
|
VALUES ($1, $2, $3, $4, $5, TRUE)
|
|
RETURNING id`,
|
|
[name, type, icon, color, userId],
|
|
);
|
|
const createdId = Number(result.rows[0].id);
|
|
cache.categories.set(key, createdId);
|
|
return createdId;
|
|
}
|
|
|
|
async function getLatestExchangeRate(client, cache, fromCurrency, toCurrency) {
|
|
const key = `${fromCurrency}->${toCurrency}`;
|
|
if (cache.exchangeRates.has(key)) {
|
|
return cache.exchangeRates.get(key);
|
|
}
|
|
const { rows } = await client.query(
|
|
`SELECT rate
|
|
FROM finance_exchange_rates
|
|
WHERE from_currency = $1 AND to_currency = $2
|
|
ORDER BY date DESC
|
|
LIMIT 1`,
|
|
[fromCurrency, toCurrency],
|
|
);
|
|
const rate = rows[0] ? Number(rows[0].rate) : 1;
|
|
cache.exchangeRates.set(key, rate);
|
|
return rate;
|
|
}
|
|
|
|
async function insertTransactions(client, transactions, cache) {
|
|
for (const item of transactions) {
|
|
const createdAt =
|
|
item.createdAt ??
|
|
new Date(`${item.transactionDate}T00:00:00Z`).toISOString();
|
|
const status = item.status ?? 'approved';
|
|
const statusUpdatedAt =
|
|
item.statusUpdatedAt ?? createdAt ?? new Date().toISOString();
|
|
const approvedAt =
|
|
item.approvedAt ??
|
|
(status === 'approved' || status === 'paid' ? statusUpdatedAt : null);
|
|
const approvedBy =
|
|
status === 'approved' || status === 'paid'
|
|
? (item.approvedBy ?? null)
|
|
: null;
|
|
|
|
const rate =
|
|
item.exchangeRate ??
|
|
(await getLatestExchangeRate(client, cache, item.currency, 'CNY'));
|
|
|
|
const amountInBase = +(item.amount * rate).toFixed(2);
|
|
|
|
await client.query(
|
|
`INSERT INTO finance_transactions (
|
|
type,
|
|
amount,
|
|
currency,
|
|
exchange_rate_to_base,
|
|
amount_in_base,
|
|
category_id,
|
|
account_id,
|
|
transaction_date,
|
|
description,
|
|
project,
|
|
memo,
|
|
created_at,
|
|
status,
|
|
status_updated_at,
|
|
reimbursement_batch,
|
|
review_notes,
|
|
submitted_by,
|
|
approved_by,
|
|
approved_at,
|
|
is_deleted
|
|
)
|
|
VALUES (
|
|
$1, $2, $3, $4, $5, $6, $7, $8, $9, $10,
|
|
$11, $12, $13, $14, $15, $16, $17, $18, $19, $20
|
|
)`,
|
|
[
|
|
item.type,
|
|
item.amount,
|
|
item.currency,
|
|
rate,
|
|
amountInBase,
|
|
item.categoryId ?? null,
|
|
item.accountId ?? null,
|
|
item.transactionDate,
|
|
item.description ?? '',
|
|
item.project ?? null,
|
|
item.memo ?? null,
|
|
createdAt,
|
|
status,
|
|
statusUpdatedAt,
|
|
item.reimbursementBatch ?? null,
|
|
item.reviewNotes ?? null,
|
|
item.submittedBy ?? null,
|
|
approvedBy,
|
|
approvedAt,
|
|
item.isDeleted ?? false,
|
|
],
|
|
);
|
|
}
|
|
}
|
|
|
|
async function importNewFormat(client, header, rows, cache) {
|
|
const indexMap = Object.fromEntries(
|
|
Object.entries(NEW_HEADER_KEYS).map(([key, label]) => [
|
|
key,
|
|
header.indexOf(label),
|
|
]),
|
|
);
|
|
|
|
const requiredIndexes = Object.values(indexMap);
|
|
if (requiredIndexes.includes(-1)) {
|
|
throw new Error('CSV 表头缺少必需字段,无法导入新版格式数据');
|
|
}
|
|
|
|
await ensureCurrency(client, cache, 'CNY', '人民币', '¥');
|
|
await ensureExchangeRate(
|
|
client,
|
|
cache,
|
|
'CNY',
|
|
'CNY',
|
|
1,
|
|
'1970-01-01',
|
|
'system',
|
|
);
|
|
|
|
const transactions = [];
|
|
|
|
for (const columns of rows) {
|
|
if (columns.length < header.length) {
|
|
continue;
|
|
}
|
|
const date = columns[indexMap.date]?.trim();
|
|
if (!date) {
|
|
continue;
|
|
}
|
|
|
|
const typeRaw = columns[indexMap.type]?.trim();
|
|
const type = resolveTransactionType(typeRaw);
|
|
|
|
const categoryInfo = parseCategoryWithIcon(columns[indexMap.category]);
|
|
const currency = (columns[indexMap.currency] || 'CNY')
|
|
.toString()
|
|
.trim()
|
|
.toUpperCase();
|
|
const currencyName = currency === 'CNY' ? '人民币' : currency;
|
|
const currencySymbol = resolveCurrencySymbol(currency);
|
|
const accountIcon = resolveCurrencyIcon(currency);
|
|
const accountColor = resolveCurrencyColor(currency);
|
|
|
|
await ensureCurrency(client, cache, currency, currencyName, currencySymbol);
|
|
await ensureExchangeRate(client, cache, currency, 'CNY', 1, date);
|
|
|
|
const accountName = columns[indexMap.account]?.trim() || '默认账户';
|
|
const accountId = await ensureAccount(client, cache, {
|
|
name: accountName,
|
|
currency,
|
|
type: 'cash',
|
|
icon: accountIcon,
|
|
color: accountColor,
|
|
});
|
|
|
|
const categoryId = await ensureCategory(client, cache, {
|
|
name: categoryInfo.name,
|
|
type,
|
|
icon: categoryInfo.icon,
|
|
color: type === 'income' ? '#10b981' : '#fb7185',
|
|
});
|
|
|
|
const amountText = columns[indexMap.amount] ?? '0';
|
|
const amount = Number(amountText.toString().replaceAll(',', '')) || 0;
|
|
if (amount === 0) {
|
|
continue;
|
|
}
|
|
|
|
const description = columns[indexMap.project]?.trim() ?? '';
|
|
const createdAt = `${date}T09:00:00.000Z`;
|
|
|
|
transactions.push({
|
|
type,
|
|
amount: Math.abs(amount),
|
|
currency,
|
|
exchangeRate: 1,
|
|
categoryId,
|
|
accountId,
|
|
transactionDate: date,
|
|
description,
|
|
createdAt,
|
|
statusUpdatedAt: createdAt,
|
|
approvedAt: createdAt,
|
|
});
|
|
}
|
|
|
|
await insertTransactions(client, transactions, cache);
|
|
return transactions.length;
|
|
}
|
|
|
|
async function importLegacyFormat(client, header, rows, cache, baseYear) {
|
|
const DATE_IDX = header.indexOf('日期');
|
|
const PROJECT_IDX = header.indexOf('项目');
|
|
const TYPE_IDX = header.indexOf('收支');
|
|
const AMOUNT_IDX = header.indexOf('金额');
|
|
const ACCOUNT_IDX = header.indexOf('支出人');
|
|
const CATEGORY_IDX = header.indexOf('计入');
|
|
const SHARE_IDX = header.indexOf('阿德应得分红');
|
|
|
|
if (
|
|
DATE_IDX === -1 ||
|
|
PROJECT_IDX === -1 ||
|
|
TYPE_IDX === -1 ||
|
|
AMOUNT_IDX === -1 ||
|
|
ACCOUNT_IDX === -1 ||
|
|
CATEGORY_IDX === -1
|
|
) {
|
|
throw new Error('CSV 表头缺少必需字段,无法导入旧版格式数据');
|
|
}
|
|
|
|
for (const currency of LEGACY_BASE_CURRENCIES) {
|
|
await ensureCurrency(
|
|
client,
|
|
cache,
|
|
currency.code,
|
|
currency.name,
|
|
currency.symbol,
|
|
);
|
|
}
|
|
|
|
for (const rate of LEGACY_BASE_EXCHANGE_RATES) {
|
|
await ensureExchangeRate(
|
|
client,
|
|
cache,
|
|
rate.fromCurrency,
|
|
rate.toCurrency,
|
|
rate.rate,
|
|
`${baseYear}-01-01`,
|
|
rate.source,
|
|
);
|
|
}
|
|
|
|
const monthTracker = { lastMonth: null, wrapped: false };
|
|
let carryDate = '';
|
|
|
|
const transactions = [];
|
|
|
|
for (const rawColumns of rows) {
|
|
const columns = [...rawColumns];
|
|
while (columns.length < header.length) {
|
|
columns.push('');
|
|
}
|
|
|
|
const rawDate = columns[DATE_IDX]?.trim();
|
|
if (rawDate) {
|
|
carryDate = normalizeDate(rawDate, monthTracker, baseYear);
|
|
}
|
|
if (!carryDate) {
|
|
continue;
|
|
}
|
|
|
|
const project = columns[PROJECT_IDX]?.trim();
|
|
const typeText = columns[TYPE_IDX]?.trim();
|
|
const amountRaw = columns[AMOUNT_IDX]?.trim();
|
|
const accountNameRaw = columns[ACCOUNT_IDX]?.trim();
|
|
const categoryRaw = columns[CATEGORY_IDX]?.trim();
|
|
const shareRaw = SHARE_IDX === -1 ? '' : columns[SHARE_IDX]?.trim();
|
|
|
|
const amount = parseAmount(amountRaw);
|
|
if (!amount) {
|
|
continue;
|
|
}
|
|
|
|
const normalizedType = resolveTransactionType(typeText);
|
|
const accountName = accountNameRaw || '美金现金';
|
|
const currency = inferCurrency(accountNameRaw, amountRaw);
|
|
const accountIcon = resolveCurrencyIcon(currency);
|
|
const accountColor = resolveCurrencyColor(currency);
|
|
|
|
const accountId = await ensureAccount(client, cache, {
|
|
name: accountName,
|
|
currency,
|
|
type: 'cash',
|
|
icon: accountIcon,
|
|
color: accountColor,
|
|
});
|
|
|
|
const categoryName =
|
|
categoryRaw ||
|
|
(normalizedType === 'income' ? '未分类收入' : '未分类支出');
|
|
const categoryId = await ensureCategory(client, cache, {
|
|
name: categoryName,
|
|
type: normalizedType,
|
|
icon: normalizedType === 'income' ? '💰' : '🏷️',
|
|
color: normalizedType === 'income' ? '#10b981' : '#fb7185',
|
|
});
|
|
|
|
const descriptionParts = [];
|
|
if (project) descriptionParts.push(project);
|
|
if (categoryRaw) descriptionParts.push(`计入: ${categoryRaw}`);
|
|
if (shareRaw) descriptionParts.push(`分红: ${shareRaw}`);
|
|
const description = descriptionParts.join(' | ');
|
|
|
|
transactions.push({
|
|
type: normalizedType,
|
|
amount: Math.abs(amount),
|
|
currency,
|
|
categoryId,
|
|
accountId,
|
|
transactionDate: carryDate,
|
|
description,
|
|
project: project || null,
|
|
memo: shareRaw || null,
|
|
});
|
|
}
|
|
|
|
await insertTransactions(client, transactions, cache);
|
|
return transactions.length;
|
|
}
|
|
|
|
async function main() {
|
|
const params = parseArgs(process.argv.slice(2));
|
|
if (!params.csv) {
|
|
console.error('请通过 --csv <路径> 指定 CSV 数据文件');
|
|
process.exit(1);
|
|
}
|
|
|
|
const inputPath = path.resolve(params.csv);
|
|
if (!fs.existsSync(inputPath)) {
|
|
console.error(`无法找到 CSV 文件: ${inputPath}`);
|
|
process.exit(1);
|
|
}
|
|
|
|
const baseYear = params.year ? Number(params.year) : 2025;
|
|
if (Number.isNaN(baseYear)) {
|
|
console.error('参数 --year 必须为数字');
|
|
process.exit(1);
|
|
}
|
|
|
|
const csvContent = fs.readFileSync(inputPath, 'utf8');
|
|
const { header, rows } = parseCsv(csvContent);
|
|
|
|
if (header.length === 0 || rows.length === 0) {
|
|
console.error('CSV 文件内容为空');
|
|
process.exit(1);
|
|
}
|
|
|
|
const isNewFormat = Object.values(NEW_HEADER_KEYS).every((key) =>
|
|
header.includes(key),
|
|
);
|
|
|
|
const pool = new Pool({
|
|
connectionString: DEFAULT_CONNECTION_STRING,
|
|
max: 10,
|
|
});
|
|
|
|
const cache = {
|
|
currencies: new Set(),
|
|
exchangeRates: new Map(),
|
|
accounts: new Map(),
|
|
categories: new Map(),
|
|
};
|
|
|
|
let client;
|
|
try {
|
|
client = await pool.connect();
|
|
await client.query('BEGIN');
|
|
await resetFinanceTables(client);
|
|
|
|
let count = 0;
|
|
count = await (isNewFormat
|
|
? importNewFormat(client, header, rows, cache)
|
|
: importLegacyFormat(client, header, rows, cache, baseYear));
|
|
|
|
await client.query('COMMIT');
|
|
console.log(`导入完成,共写入 ${count} 条交易记录`);
|
|
process.exit(0);
|
|
} catch (error) {
|
|
if (client) {
|
|
await client.query('ROLLBACK').catch(() => {});
|
|
}
|
|
console.error('导入数据失败:', error);
|
|
process.exit(1);
|
|
} finally {
|
|
if (client) {
|
|
client.release();
|
|
}
|
|
await pool.end();
|
|
}
|
|
}
|
|
|
|
main().catch((error) => {
|
|
console.error('导入流程异常终止:', error);
|
|
process.exit(1);
|
|
});
|