Files
kt-financial-system/apps/backend/utils/sqlite.ts
2025-11-04 16:06:44 +08:00

161 lines
4.2 KiB
TypeScript

import { mkdirSync } from 'node:fs';
import Database from 'better-sqlite3';
import { dirname, join } from 'pathe';
const dbFile = join(process.cwd(), 'storage', 'finance.db');
mkdirSync(dirname(dbFile), { recursive: true });
const database = new Database(dbFile);
function assertIdentifier(name: string) {
if (!/^[A-Za-z_][A-Za-z0-9_]*$/.test(name)) {
throw new Error(`Invalid identifier: ${name}`);
}
return name;
}
function ensureColumn(table: string, column: string, definition: string) {
const safeTable = assertIdentifier(table);
const safeColumn = assertIdentifier(column);
const columns = database
.prepare<{ name: string }>(`PRAGMA table_info(${safeTable})`)
.all();
if (!columns.some((item) => item.name === safeColumn)) {
database.exec(`ALTER TABLE ${safeTable} ADD COLUMN ${definition}`);
}
}
database.pragma('journal_mode = WAL');
database.exec(`
CREATE TABLE IF NOT EXISTS finance_currencies (
code TEXT PRIMARY KEY,
name TEXT NOT NULL,
symbol TEXT NOT NULL,
is_base INTEGER NOT NULL DEFAULT 0,
is_active INTEGER NOT NULL DEFAULT 1
);
`);
database.exec(`
CREATE TABLE IF NOT EXISTS finance_exchange_rates (
id INTEGER PRIMARY KEY AUTOINCREMENT,
from_currency TEXT NOT NULL,
to_currency TEXT NOT NULL,
rate REAL NOT NULL,
date TEXT NOT NULL,
source TEXT DEFAULT 'manual'
);
`);
database.exec(`
CREATE TABLE IF NOT EXISTS finance_accounts (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT NOT NULL,
currency TEXT NOT NULL,
type TEXT DEFAULT 'cash',
icon TEXT,
color TEXT,
user_id INTEGER DEFAULT 1,
is_active INTEGER DEFAULT 1
);
`);
database.exec(`
CREATE TABLE IF NOT EXISTS finance_categories (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name TEXT NOT NULL,
type TEXT NOT NULL,
icon TEXT,
color TEXT,
user_id INTEGER DEFAULT 1,
is_active INTEGER DEFAULT 1
);
`);
database.exec(`
CREATE TABLE IF NOT EXISTS finance_transactions (
id INTEGER PRIMARY KEY AUTOINCREMENT,
type TEXT NOT NULL,
amount REAL NOT NULL,
currency TEXT NOT NULL,
exchange_rate_to_base REAL NOT NULL,
amount_in_base REAL NOT NULL,
category_id INTEGER,
account_id INTEGER,
transaction_date TEXT NOT NULL,
description TEXT,
project TEXT,
memo TEXT,
created_at TEXT NOT NULL,
status TEXT NOT NULL DEFAULT 'approved',
status_updated_at TEXT,
reimbursement_batch TEXT,
review_notes TEXT,
submitted_by TEXT,
approved_by TEXT,
approved_at TEXT,
is_deleted INTEGER NOT NULL DEFAULT 0,
deleted_at TEXT,
FOREIGN KEY (currency) REFERENCES finance_currencies(code),
FOREIGN KEY (category_id) REFERENCES finance_categories(id),
FOREIGN KEY (account_id) REFERENCES finance_accounts(id)
);
`);
ensureColumn(
'finance_transactions',
'status',
"status TEXT NOT NULL DEFAULT 'approved'",
);
ensureColumn('finance_transactions', 'status_updated_at', 'status_updated_at TEXT');
ensureColumn(
'finance_transactions',
'reimbursement_batch',
'reimbursement_batch TEXT',
);
ensureColumn('finance_transactions', 'review_notes', 'review_notes TEXT');
ensureColumn('finance_transactions', 'submitted_by', 'submitted_by TEXT');
ensureColumn('finance_transactions', 'approved_by', 'approved_by TEXT');
ensureColumn('finance_transactions', 'approved_at', 'approved_at TEXT');
database.exec(`
CREATE TABLE IF NOT EXISTS finance_media_messages (
id INTEGER PRIMARY KEY AUTOINCREMENT,
chat_id INTEGER NOT NULL,
message_id INTEGER 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 TEXT NOT NULL,
updated_at TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP,
UNIQUE(chat_id, message_id)
);
`);
database.exec(`
CREATE INDEX IF NOT EXISTS idx_finance_media_messages_created_at
ON finance_media_messages (created_at DESC);
`);
database.exec(`
CREATE INDEX IF NOT EXISTS idx_finance_media_messages_user_id
ON finance_media_messages (user_id);
`);
export default database;