-- migrations/XXXXXX_init_banking_schema.sql -- Complete schema for multi-bank transaction aggregation -- Table: user_consents -- Stores consent IDs granted by users for each bank CREATE TABLE IF NOT EXISTS user_consents ( id SERIAL PRIMARY KEY, user_id VARCHAR(50) NOT NULL, bank_code VARCHAR(20) NOT NULL, consent_id VARCHAR(100) NOT NULL, status VARCHAR(20) NOT NULL DEFAULT 'active', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), expires_at TIMESTAMPTZ NOT NULL, UNIQUE(user_id, bank_code) ); CREATE INDEX IF NOT EXISTS idx_user_consents_user_bank ON user_consents(user_id, bank_code); CREATE INDEX IF NOT EXISTS idx_user_consents_consent_id ON user_consents(consent_id); -- Table: accounts -- Stores all bank accounts across all banks for all users CREATE TABLE IF NOT EXISTS accounts ( id SERIAL PRIMARY KEY, account_id VARCHAR(50) NOT NULL, user_id VARCHAR(50) NOT NULL, bank_code VARCHAR(20) NOT NULL, status VARCHAR(20), currency VARCHAR(3) NOT NULL, account_type VARCHAR(50) NOT NULL, account_sub_type VARCHAR(50), nickname VARCHAR(255) NOT NULL, description TEXT, opening_date DATE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(account_id, bank_code) ); CREATE INDEX IF NOT EXISTS idx_accounts_user_id ON accounts(user_id); CREATE INDEX IF NOT EXISTS idx_accounts_bank_code ON accounts(bank_code); -- Table: transactions -- Stores all transactions from all accounts CREATE TABLE IF NOT EXISTS transactions ( id SERIAL PRIMARY KEY, transaction_id VARCHAR(100) NOT NULL, account_id VARCHAR(50) NOT NULL, bank_code VARCHAR(20) NOT NULL, amount NUMERIC(15, 2) NOT NULL, currency VARCHAR(3) NOT NULL, credit_debit_indicator VARCHAR(10) NOT NULL, status VARCHAR(20) NOT NULL, booking_date_time TIMESTAMPTZ NOT NULL, value_date_time TIMESTAMPTZ, transaction_information TEXT, bank_transaction_code VARCHAR(50), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(transaction_id, bank_code) ); CREATE INDEX IF NOT EXISTS idx_transactions_account_id ON transactions(account_id); CREATE INDEX IF NOT EXISTS idx_transactions_booking_date ON transactions(booking_date_time); CREATE INDEX IF NOT EXISTS idx_transactions_bank_code ON transactions(bank_code);