-- Migration: 014_PaymentAllocations.sql -- Description: Payment allocations and suggested matches for bank reconciliation -- Date: 2026-01-18 -- Phase: 3 of Invoicing Implementation -- Payment allocations table -- Records confirmed matches between bank transactions and invoices/credit notes CREATE TABLE IF NOT EXISTS payment_allocations ( id TEXT PRIMARY KEY, company_id VARCHAR(255) NOT NULL, -- Source: bank transaction bank_transaction_id VARCHAR(255) NOT NULL, -- Target: invoice or credit note (one must be set) invoice_id VARCHAR(255), credit_note_id VARCHAR(255), -- Allocation details amount DECIMAL(18, 2) NOT NULL, allocation_type VARCHAR(20) NOT NULL, -- 'payment', 'credit_note', 'refund' -- Match metadata match_method VARCHAR(50) NOT NULL, -- 'manual', 'auto_amount', 'auto_reference', 'auto_name' match_confidence DECIMAL(3, 2), -- 0.00 to 1.00 -- Ledger integration ledger_transaction_id VARCHAR(255), -- Audit created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), created_by VARCHAR(255) NOT NULL, -- Constraints CONSTRAINT chk_allocation_target CHECK ( (invoice_id IS NOT NULL AND credit_note_id IS NULL) OR (invoice_id IS NULL AND credit_note_id IS NOT NULL) ), CONSTRAINT chk_allocation_type CHECK ( allocation_type IN ('payment', 'credit_note', 'refund') ) ); -- Indexes for payment allocations CREATE INDEX IF NOT EXISTS idx_payment_allocation_company ON payment_allocations(company_id); CREATE INDEX IF NOT EXISTS idx_payment_allocation_bank_tx ON payment_allocations(bank_transaction_id); CREATE INDEX IF NOT EXISTS idx_payment_allocation_invoice ON payment_allocations(invoice_id) WHERE invoice_id IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_payment_allocation_credit_note ON payment_allocations(credit_note_id) WHERE credit_note_id IS NOT NULL; -- Unique constraint: one allocation per bank transaction per invoice CREATE UNIQUE INDEX IF NOT EXISTS idx_payment_allocation_unique ON payment_allocations(bank_transaction_id, invoice_id) WHERE invoice_id IS NOT NULL; -- Suggested payment matches table -- Stores AI/algorithm suggested matches for user review CREATE TABLE IF NOT EXISTS suggested_payment_matches ( id TEXT PRIMARY KEY DEFAULT gen_random_uuid()::text, company_id VARCHAR(255) NOT NULL, -- Source: bank transaction bank_transaction_id VARCHAR(255) NOT NULL, -- Target: invoice invoice_id VARCHAR(255) NOT NULL, -- Match scoring confidence DECIMAL(3, 2) NOT NULL, -- 0.00 to 1.00 match_reasons JSONB DEFAULT '[]', -- Array of { reason, score } suggested_amount DECIMAL(18, 2) NOT NULL, -- Status tracking status VARCHAR(20) NOT NULL DEFAULT 'pending', -- 'pending', 'accepted', 'rejected', 'expired' -- Timestamps created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), reviewed_at TIMESTAMP WITH TIME ZONE, reviewed_by VARCHAR(255), -- Constraints CONSTRAINT chk_match_status CHECK ( status IN ('pending', 'accepted', 'rejected', 'expired') ), CONSTRAINT chk_confidence_range CHECK ( confidence >= 0 AND confidence <= 1 ) ); -- Indexes for suggested matches CREATE INDEX IF NOT EXISTS idx_suggested_match_company ON suggested_payment_matches(company_id); CREATE INDEX IF NOT EXISTS idx_suggested_match_bank_tx ON suggested_payment_matches(bank_transaction_id); CREATE INDEX IF NOT EXISTS idx_suggested_match_invoice ON suggested_payment_matches(invoice_id); CREATE INDEX IF NOT EXISTS idx_suggested_match_status ON suggested_payment_matches(status); CREATE INDEX IF NOT EXISTS idx_suggested_match_confidence ON suggested_payment_matches(confidence DESC); -- Unique constraint: one pending suggestion per bank transaction per invoice CREATE UNIQUE INDEX IF NOT EXISTS idx_suggested_match_unique ON suggested_payment_matches(bank_transaction_id, invoice_id) WHERE status = 'pending'; -- Comments COMMENT ON TABLE payment_allocations IS 'Confirmed matches between bank transactions and invoices/credit notes'; COMMENT ON TABLE suggested_payment_matches IS 'AI/algorithm suggested matches for bank reconciliation'; COMMENT ON COLUMN suggested_payment_matches.match_reasons IS 'JSON array of matching reasons: [{"reason": "exact_amount", "score": 0.8}, {"reason": "reference_match", "score": 0.15}]';