import process from 'node:process'; import type { PoolClient } from 'pg'; import { Pool } from 'pg'; import { MOCK_ACCOUNTS, MOCK_CATEGORIES, MOCK_CURRENCIES, MOCK_EXCHANGE_RATES, } from './mock-data'; const DEFAULT_HOST = process.env.POSTGRES_HOST ?? 'postgres'; const DEFAULT_PORT = Number.parseInt(process.env.POSTGRES_PORT ?? '5432', 10); const DEFAULT_DB = process.env.POSTGRES_DB ?? 'kt_financial'; const DEFAULT_USER = process.env.POSTGRES_USER ?? 'kt_financial'; const DEFAULT_PASSWORD = process.env.POSTGRES_PASSWORD ?? 'kt_financial_pwd'; const connectionString = process.env.POSTGRES_URL ?? `postgresql://${DEFAULT_USER}:${DEFAULT_PASSWORD}@${DEFAULT_HOST}:${DEFAULT_PORT}/${DEFAULT_DB}`; const pool = new Pool({ connectionString, max: 10, }); let initPromise: null | Promise = null; async function seedCurrencies(client: PoolClient) { await Promise.all( MOCK_CURRENCIES.map((currency) => client.query( `INSERT INTO finance_currencies (code, name, symbol, is_base, is_active) VALUES ($1, $2, $3, $4, $5) ON CONFLICT (code) DO NOTHING`, [ currency.code, currency.name, currency.symbol, currency.isBase, currency.isActive, ], ), ), ); } async function seedExchangeRates(client: PoolClient) { await Promise.all( MOCK_EXCHANGE_RATES.map((rate) => client.query( `INSERT INTO finance_exchange_rates (from_currency, to_currency, rate, date, source) VALUES ($1, $2, $3, $4, $5) ON CONFLICT DO NOTHING`, [ rate.fromCurrency, rate.toCurrency, rate.rate, rate.date, rate.source ?? 'manual', ], ), ), ); } async function seedAccounts(client: PoolClient) { await Promise.all( MOCK_ACCOUNTS.map((account) => client.query( `INSERT INTO finance_accounts (id, name, currency, type, icon, color, user_id, is_active) VALUES ($1, $2, $3, $4, $5, $6, $7, $8) ON CONFLICT (id) DO NOTHING`, [ account.id, account.name, account.currency, account.type, account.icon, account.color, account.userId ?? 1, account.isActive, ], ), ), ); } async function seedCategories(client: PoolClient) { await Promise.all( MOCK_CATEGORIES.map((category) => client.query( `INSERT INTO finance_categories (id, name, type, icon, color, user_id, is_active) VALUES ($1, $2, $3, $4, $5, $6, $7) ON CONFLICT (id) DO NOTHING`, [ category.id, category.name, category.type, category.icon, category.color, category.userId, category.isActive, ], ), ), ); } async function initializeSchema() { const client = await pool.connect(); try { await client.query('BEGIN'); 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); `); await seedCurrencies(client); await seedExchangeRates(client); await seedAccounts(client); await seedCategories(client); await client.query('COMMIT'); } catch (error) { await client.query('ROLLBACK'); throw error; } finally { client.release(); } } export async function getPool() { if (!initPromise) { initPromise = initializeSchema(); } await initPromise; return pool; } export async function query(text: string, params?: any[]) { const client = await getPool(); const result = await client.query(text, params); return result; } export async function withTransaction( handler: (client: PoolClient) => Promise, ) { const client = await pool.connect(); try { await client.query('BEGIN'); const result = await handler(client); await client.query('COMMIT'); return result; } catch (error) { await client.query('ROLLBACK'); throw error; } finally { client.release(); } }