-- Migration: 009_BankTransactions -- Description: Create bank_transactions table for storing synced transactions from Enable Banking -- Used by BankTransactionSyncJob (Hangfire) and displayed in Hurtig Bogføring CREATE TABLE IF NOT EXISTS bank_transactions ( id TEXT PRIMARY KEY, company_id TEXT NOT NULL, bank_connection_id TEXT NOT NULL, bank_account_id TEXT NOT NULL, external_id TEXT NOT NULL, -- Transaction ID from Enable Banking (for idempotency) -- Amount and currency amount DECIMAL(18,2) NOT NULL, currency TEXT NOT NULL DEFAULT 'DKK', -- Dates transaction_date DATE NOT NULL, booking_date DATE, value_date DATE, -- Transaction details description TEXT, counterparty_name TEXT, counterparty_account TEXT, reference TEXT, creditor_name TEXT, debtor_name TEXT, -- Status tracking status TEXT NOT NULL DEFAULT 'pending', -- pending | booked | ignored journal_entry_draft_id TEXT, -- Reference to kassekladde when booked -- Raw data for debugging/auditing raw_data JSONB, -- Timestamps created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), -- Ensure no duplicate transactions per company UNIQUE(company_id, external_id) ); -- Index for fetching pending transactions by company (main query) CREATE INDEX IF NOT EXISTS idx_bank_tx_company_status ON bank_transactions(company_id, status); -- Index for date-based queries CREATE INDEX IF NOT EXISTS idx_bank_tx_company_date ON bank_transactions(company_id, transaction_date DESC); -- Index for bank account filtering CREATE INDEX IF NOT EXISTS idx_bank_tx_bank_account ON bank_transactions(bank_account_id, status); -- Index for checking existing transactions during sync CREATE INDEX IF NOT EXISTS idx_bank_tx_external_id ON bank_transactions(company_id, external_id); COMMENT ON TABLE bank_transactions IS 'Bank transactions synced from Enable Banking API via Hangfire job'; COMMENT ON COLUMN bank_transactions.external_id IS 'Unique transaction ID from Enable Banking, used for deduplication'; COMMENT ON COLUMN bank_transactions.status IS 'pending = not yet booked, booked = linked to journal entry, ignored = manually skipped'; COMMENT ON COLUMN bank_transactions.journal_entry_draft_id IS 'Reference to journal_entry_draft_read_models.aggregate_id when booked';