CREATE TABLE IF NOT EXISTS users ( id BIGSERIAL PRIMARY KEY, first_name VARCHAR(255) NOT NULL, last_name VARCHAR(255) NOT NULL, email VARCHAR(255) UNIQUE, phone_number VARCHAR(20) UNIQUE, role VARCHAR(50) NOT NULL, password BYTEA NOT NULL, email_verified BOOLEAN NOT NULL DEFAULT FALSE, phone_verified BOOLEAN NOT NULL DEFAULT FALSE, created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMPTZ, company_id BIGINT, suspended_at TIMESTAMPTZ NULL, -- this can be NULL if the user is not suspended suspended BOOLEAN NOT NULL DEFAULT FALSE, CHECK ( email IS NOT NULL OR phone_number IS NOT NULL ), UNIQUE (email, company_id), UNIQUE (phone_number, company_id) ); CREATE TABLE IF NOT EXISTS virtual_game_providers ( id BIGSERIAL PRIMARY KEY, provider_id VARCHAR(100) UNIQUE NOT NULL, -- providerId from Veli Games provider_name VARCHAR(255) NOT NULL, logo_dark TEXT, logo_light TEXT, -- logoForLight (URL) enabled BOOLEAN NOT NULL DEFAULT TRUE, -- allow enabling/disabling providers created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMPTZ ); CREATE TABLE IF NOT EXISTS virtual_game_provider_reports ( id BIGSERIAL PRIMARY KEY, provider_id VARCHAR(100) NOT NULL REFERENCES virtual_game_providers(provider_id) ON DELETE CASCADE, report_date DATE NOT NULL, total_games_played BIGINT DEFAULT 0, total_bets NUMERIC(18,2) DEFAULT 0, total_payouts NUMERIC(18,2) DEFAULT 0, total_profit NUMERIC(18,2) GENERATED ALWAYS AS (total_bets - total_payouts) STORED, total_players BIGINT DEFAULT 0, report_type VARCHAR(50) DEFAULT 'daily', created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMPTZ ); CREATE UNIQUE INDEX IF NOT EXISTS idx_unique_provider_report ON virtual_game_provider_reports (provider_id, report_date, report_type); CREATE TABLE IF NOT EXISTS virtual_games ( id BIGSERIAL PRIMARY KEY, game_id VARCHAR(150) UNIQUE NOT NULL, provider_id VARCHAR(100) NOT NULL REFERENCES virtual_game_providers(provider_id) ON DELETE CASCADE, name VARCHAR(255) NOT NULL, category VARCHAR(100), device_type VARCHAR(100), volatility VARCHAR(50), rtp NUMERIC(5, 2), has_demo BOOLEAN DEFAULT FALSE, has_free_bets BOOLEAN DEFAULT FALSE, bets NUMERIC [] DEFAULT '{}', thumbnail TEXT, status INT, created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMPTZ ); CREATE UNIQUE INDEX IF NOT EXISTS ux_virtual_games_provider_game ON virtual_games (provider_id, game_id); CREATE TABLE IF NOT EXISTS virtual_game_reports ( id BIGSERIAL PRIMARY KEY, game_id VARCHAR(150) NOT NULL REFERENCES virtual_games(game_id) ON DELETE CASCADE, provider_id VARCHAR(100) NOT NULL REFERENCES virtual_game_providers(provider_id) ON DELETE CASCADE, report_date DATE NOT NULL, total_rounds BIGINT DEFAULT 0, total_bets NUMERIC(18,2) DEFAULT 0, total_payouts NUMERIC(18,2) DEFAULT 0, total_profit NUMERIC(18,2) GENERATED ALWAYS AS (total_bets - total_payouts) STORED, total_players BIGINT DEFAULT 0, report_type VARCHAR(50) DEFAULT 'daily', created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMPTZ ); CREATE UNIQUE INDEX IF NOT EXISTS idx_unique_game_report ON virtual_game_reports (game_id, report_date, report_type); CREATE TABLE IF NOT EXISTS wallets ( id BIGSERIAL PRIMARY KEY, balance BIGINT NOT NULL DEFAULT 0, currency VARCHAR(3) NOT NULL DEFAULT 'ETB', is_withdraw BOOLEAN NOT NULL, is_bettable BOOLEAN NOT NULL, is_transferable BOOLEAN NOT NULL, user_id BIGINT NOT NULL, type TEXT NOT NULL CHECK ( type IN ( 'regular_wallet', 'static_wallet', 'branch_wallet', 'company_wallet' ) ), is_active BOOLEAN NOT NULL DEFAULT true, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, CONSTRAINT balance_positve CHECK (balance >= 0) ); CREATE TABLE wallet_stats ( wallet_id BIGINT NOT NULL, wallet_user_id BIGINT NOT NULL, wallet_user_first_name TEXT NOT NULL, wallet_user_last_name TEXT NOT NULL, wallet_type TEXT NOT NULL, interval_start TIMESTAMP NOT NULL, number_of_transactions BIGINT NOT NULL, total_transactions BIGINT NOT NULL, number_of_deposits BIGINT NOT NULL, total_deposits_amount BIGINT NOT NULL, number_of_withdraws BIGINT NOT NULL, total_withdraws_amount BIGINT NOT NULL, number_of_transfers BIGINT NOT NULL, total_transfers_amount BIGINT NOT NULL, updated_at TIMESTAMP DEFAULT now(), UNIQUE(wallet_id, interval_start) ); CREATE TABLE refresh_tokens ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL, token TEXT NOT NULL UNIQUE, expires_at TIMESTAMPTZ NOT NULL, created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, revoked BOOLEAN DEFAULT FALSE NOT NULL, CONSTRAINT unique_token UNIQUE (token) ); ----- CREATE TABLE otps ( id BIGSERIAL PRIMARY KEY, sent_to VARCHAR(255) NOT NULL, medium VARCHAR(50) NOT NULL, otp_for VARCHAR(50) NOT NULL, otp VARCHAR(10) NOT NULL, used BOOLEAN NOT NULL DEFAULT FALSE, used_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, expires_at TIMESTAMPTZ NOT NULL ); CREATE TABLE IF NOT EXISTS bets ( id BIGSERIAL PRIMARY KEY, company_id BIGINT NOT NULL, amount BIGINT NOT NULL, total_odds REAL NOT NULL, potential_win BIGINT GENERATED ALWAYS AS (amount * total_odds) STORED, status INT NOT NULL, user_id BIGINT NOT NULL, is_shop_bet BOOLEAN NOT NULL, cashed_out BOOLEAN NOT NULL DEFAULT false, outcomes_hash TEXT NOT NULL, fast_code VARCHAR(10) NOT NULL, processed BOOLEAN DEFAULT FALSE NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS tickets ( id BIGSERIAL PRIMARY KEY, company_id BIGINT NOT NULL, amount BIGINT NOT NULL, total_odds REAL NOT NULL, IP VARCHAR(255) NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE exchange_rates ( id SERIAL PRIMARY KEY, from_currency VARCHAR(3) NOT NULL, to_currency VARCHAR(3) NOT NULL, rate DECIMAL(19, 6) NOT NULL, valid_until TIMESTAMP NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT NOW (), UNIQUE (from_currency, to_currency) ); CREATE TABLE IF NOT EXISTS bet_outcomes ( id BIGSERIAL PRIMARY KEY, bet_id BIGINT NOT NULL, sport_id BIGINT NOT NULL, event_id BIGINT NOT null, odd_id BIGINT NOT NULL, home_team_name TEXT NOT NULL, away_team_name TEXT NOT NULL, market_id BIGINT NOT NULL, market_name TEXT NOT NULL, odd REAL NOT NULL, odd_name TEXT NOT NULL, odd_header TEXT NOT NULL, odd_handicap TEXT NOT NULL, status INT NOT NULL DEFAULT 0, expires TIMESTAMP NOT NULL ); CREATE TABLE IF NOT EXISTS ticket_outcomes ( id BIGSERIAL PRIMARY KEY, ticket_id BIGINT NOT NULL, event_id BIGINT NOT null, odd_id BIGINT NOT NULL, home_team_name TEXT NOT NULL, away_team_name TEXT NOT NULL, market_id BIGINT NOT NULL, market_name TEXT NOT NULL, odd REAL NOT NULL, odd_name TEXT NOT NULL, odd_header TEXT NOT NULL, odd_handicap TEXT NOT NULL, status INT NOT NULL DEFAULT 0, expires TIMESTAMP NOT NULL ); CREATE TABLE IF NOT EXISTS banks ( id BIGSERIAL PRIMARY KEY, slug VARCHAR(255) NOT NULL UNIQUE, swift VARCHAR(20) NOT NULL, name VARCHAR(255) NOT NULL, acct_length INT NOT NULL, country_id INT NOT NULL, is_mobilemoney INT, -- nullable integer (0 or 1) is_active INT NOT NULL, -- 0 or 1 is_rtgs INT NOT NULL, -- 0 or 1 active INT NOT NULL, -- 0 or 1 is_24hrs INT, -- nullable integer (0 or 1) created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL, currency VARCHAR(10) NOT NULL, bank_logo TEXT -- URL or base64 string ); -- CREATE TABLE IF NOT EXISTS wallets ( -- id BIGSERIAL PRIMARY KEY, -- balance BIGINT NOT NULL DEFAULT 0, -- is_withdraw BOOLEAN NOT NULL, -- is_bettable BOOLEAN NOT NULL, -- is_transferable BOOLEAN NOT NULL, -- user_id BIGINT NOT NULL, -- type VARCHAR(255) NOT NULL, -- is_active BOOLEAN NOT NULL DEFAULT true, -- created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, -- updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, -- CONSTRAINT balance_positve CHECK (balance >= 0) -- ); CREATE TABLE IF NOT EXISTS customer_wallets ( id BIGSERIAL PRIMARY KEY, customer_id BIGINT NOT NULL, regular_wallet_id BIGINT NOT NULL, static_wallet_id BIGINT NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS wallet_transfer ( id BIGSERIAL PRIMARY KEY, amount BIGINT, message TEXT NOT NULL, type VARCHAR(255), receiver_wallet_id BIGINT, sender_wallet_id BIGINT, cashier_id BIGINT, verified BOOLEAN DEFAULT false, reference_number VARCHAR(255) NOT NULL, ext_reference_number VARCHAR(255), session_id VARCHAR(255), status VARCHAR(255), payment_method VARCHAR(255), created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS shop_transactions ( id BIGSERIAL PRIMARY KEY, amount BIGINT NOT NULL, branch_id BIGINT NOT NULL, company_id BIGINT NOT NULL, user_id BIGINT NOT NULL, type BIGINT NOT NULL, full_name VARCHAR(255) NOT NULL, phone_number VARCHAR(255) NOT NULL, payment_option BIGINT NOT NULL, bank_code VARCHAR(255), beneficiary_name VARCHAR(255), account_name VARCHAR(255), account_number VARCHAR(255), reference_number VARCHAR(255), approved_by BIGINT, verified BOOLEAN DEFAULT false NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS shop_bets ( id BIGSERIAL PRIMARY KEY, shop_transaction_id BIGINT NOT NULL, cashout_id VARCHAR(255) NOT NULL, cashed_out_by BIGINT, bet_id BIGINT NOT NULL, number_of_outcomes BIGINT NOT NULL, cashed_out BOOLEAN DEFAULT FALSE NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE (shop_transaction_id), UNIQUE (bet_id), UNIQUE (cashout_id) ); CREATE TABLE IF NOT EXISTS shop_deposits ( id BIGSERIAL PRIMARY KEY, shop_transaction_id BIGINT NOT NULL, customer_id BIGINT NOT NULL, wallet_transfer_id BIGINT, branch_wallet_id BIGINT NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE (shop_transaction_id) ); CREATE TABLE IF NOT EXISTS branches ( id BIGSERIAL PRIMARY KEY, name VARCHAR(255) NOT NULL, location TEXT NOT NULL, profit_percent REAL NOT NULL, is_active BOOLEAN NOT NULL DEFAULT true, wallet_id BIGINT NOT NULL, branch_manager_id BIGINT NOT NULL, company_id BIGINT NOT NULL, is_self_owned BOOLEAN NOT NULL DEFAULT false, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE (wallet_id), CONSTRAINT profit_percentage_check CHECK ( profit_percent >= 0 AND profit_percent < 1 ) ); CREATE TABLE IF NOT EXISTS branch_operations ( id BIGSERIAL PRIMARY KEY, operation_id BIGINT NOT NULL, branch_id BIGINT NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS branch_cashiers ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL, branch_id BIGINT NOT NULL, UNIQUE (user_id, branch_id) ); CREATE TABLE IF NOT EXISTS branch_locations (key TEXT PRIMARY KEY, value TEXT NOT NULL); CREATE TABLE branch_stats ( branch_id BIGINT NOT NULL, branch_name TEXT NOT NULL, company_id BIGINT NOT NULL, company_name TEXT NOT NULL, company_slug TEXT NOT NULL, interval_start TIMESTAMP NOT NULL, total_bets BIGINT NOT NULL, total_stake BIGINT NOT NULL, deducted_stake BIGINT NOT NULL, total_cash_out BIGINT NOT NULL, total_cash_backs BIGINT NOT NULL, number_of_unsettled BIGINT NOT NULL, total_unsettled_amount BIGINT NOT NULL, total_cashiers BIGINT NOT NULL, updated_at TIMESTAMP DEFAULT now(), UNIQUE(branch_id, interval_start) ); CREATE TABLE events ( id BIGSERIAL PRIMARY KEY, source_event_id TEXT NOT NULL, sport_id INT NOT NULL, match_name TEXT NOT NULL, home_team TEXT NOT NULL, away_team TEXT NOT NULL, home_team_id BIGINT NOT NULL, away_team_id BIGINT NOT NULL, home_kit_image TEXT NOT NULL, away_kit_image TEXT NOT NULL, league_id BIGINT NOT NULL, league_name TEXT NOT NULL, start_time TIMESTAMP NOT NULL, score TEXT, match_minute INT, timer_status TEXT, added_time INT, match_period INT, is_live BOOLEAN NOT NULL DEFAULT false, status TEXT NOT NULL, fetched_at TIMESTAMP DEFAULT now (), updated_at TIMESTAMP DEFAULT now (), source TEXT NOT NULL DEFAULT 'b365api' CHECK ( source IN ('b365api', 'bfair', '1xbet', 'bwin', 'enetpulse') ), default_is_active BOOLEAN NOT NULL DEFAULT true, default_is_featured BOOLEAN NOT NULL DEFAULT false, default_winning_upper_limit BIGINT NOT NULL, is_monitored BOOLEAN NOT NULL DEFAULT FALSE, UNIQUE(source_event_id, source) ); CREATE INDEX idx_events_league_start_time ON events(league_id, start_time); CREATE INDEX IF NOT EXISTS idx_events_league_id ON events (league_id); CREATE EXTENSION IF NOT EXISTS pg_trgm; CREATE INDEX idx_events_search_trgm ON events USING GIN ( match_name gin_trgm_ops, league_name gin_trgm_ops ); CREATE INDEX idx_events_core_filter ON events ( source, sport_id, league_id, status, is_live, start_time DESC ); CREATE TABLE event_bet_stats ( event_id BIGINT PRIMARY KEY, number_of_bets BIGINT, total_amount BIGINT, avg_bet_amount DOUBLE PRECISION, total_potential_winnings BIGINT, updated_at TIMESTAMP DEFAULT now() ); CREATE TABLE event_history ( id BIGSERIAL PRIMARY KEY, event_id BIGINT NOT NULL, status TEXT NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE company_event_settings ( id BIGSERIAL PRIMARY KEY, company_id BIGINT NOT NULL, event_id BIGINT NOT NULL, is_active BOOLEAN, is_featured BOOLEAN, winning_upper_limit BIGINT, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE (company_id, event_id) ); CREATE TABLE odds_market ( id BIGSERIAL PRIMARY KEY, event_id BIGINT NOT NULL, market_type TEXT NOT NULL, market_name TEXT NOT NULL, market_category TEXT NOT NULL, market_id BIGINT NOT NULL, raw_odds JSONB NOT NULL, number_of_outcomes BIGINT NOT NULL, default_is_active BOOLEAN NOT NULL DEFAULT true, fetched_at TIMESTAMP DEFAULT now (), expires_at TIMESTAMP NOT NULL, UNIQUE (event_id, market_id) ); CREATE INDEX IF NOT EXISTS idx_odds_market_event_id ON odds_market (event_id); CREATE TABLE odd_history ( id BIGSERIAL PRIMARY KEY, odds_market_id BIGINT NOT NULL REFERENCES odds_market (id), raw_odd_id BIGINT NOT NULL, market_id BIGINT NOT NULL, event_id BIGINT NOT NULL, odd_value DOUBLE PRECISION NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE company_odd_settings ( id BIGSERIAL PRIMARY KEY, company_id BIGINT NOT NULL, odds_market_id BIGINT NOT NULL, is_active BOOLEAN, custom_raw_odds JSONB, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE (company_id, odds_market_id) ); CREATE TABLE global_odd_market_settings ( market_id BIGINT NOT NULL, market_name TEXT NOT NULL, is_active BOOLEAN NOT NULL DEFAULT true, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE (market_id) ); CREATE TABLE company_odd_market_settings ( market_id BIGINT NOT NULL, market_name TEXT NOT NULL, company_id BIGINT NOT NULL, is_active BOOLEAN, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE (company_id, market_id) ); CREATE TABLE result_log ( id BIGSERIAL PRIMARY KEY, status_not_finished_count INT NOT NULL, status_not_finished_bets INT NOT NULL, status_to_be_fixed_count INT NOT NULL, status_to_be_fixed_bets INT NOT NULL, status_postponed_count INT NOT NULL, status_postponed_bets INT NOT NULL, status_ended_count INT NOT NULL, status_ended_bets INT NOT NULL, status_removed_count INT NOT NULL, status_removed_bets INT NOT NULL, removed_count INT NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE companies ( id BIGSERIAL PRIMARY KEY, name TEXT NOT NULL, slug TEXT UNIQUE NOT NULL, admin_id BIGINT NOT NULL, wallet_id BIGINT NOT NULL, deducted_percentage REAL NOT NULL, is_active BOOLEAN NOT NULL DEFAULT true, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, CONSTRAINT deducted_percentage_check CHECK ( deducted_percentage > 0 AND deducted_percentage < 1 ) ); CREATE TABLE company_stats ( company_id BIGINT NOT NULL, company_name TEXT NOT NULL, company_slug TEXT NOT NULL, interval_start TIMESTAMP NOT NULL, total_bets BIGINT NOT NULL, total_stake BIGINT NOT NULL, deducted_stake BIGINT NOT NULL, total_cash_out BIGINT NOT NULL, total_cash_backs BIGINT NOT NULL, number_of_unsettled BIGINT NOT NULL, total_unsettled_amount BIGINT NOT NULL, total_admins BIGINT NOT NULL, total_managers BIGINT NOT NULL, total_cashiers BIGINT NOT NULL, total_customers BIGINT NOT NULL, total_approvers BIGINT NOT NULL, total_branches BIGINT NOT NULL, updated_at TIMESTAMP DEFAULT now(), UNIQUE(company_id, interval_start) ); CREATE TABLE leagues ( id BIGINT PRIMARY KEY, name TEXT NOT NULL, img_url TEXT, country_code TEXT, bet365_id INT, sport_id INT NOT NULL, default_is_active BOOLEAN NOT NULL DEFAULT true, default_is_featured BOOLEAN NOT NULL DEFAULT false ); CREATE TABLE company_league_settings ( id BIGSERIAL PRIMARY KEY, company_id BIGINT NOT NULL, league_id BIGINT NOT NULL, is_active BOOLEAN, is_featured BOOLEAN, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE (league_id, company_id) ); CREATE TABLE teams ( id BIGSERIAL PRIMARY KEY, team_name TEXT NOT NULL, country_code TEXT NOT NULL, bet365_id BIGINT, img_url TEXT ); CREATE TABLE IF NOT EXISTS global_settings ( key TEXT PRIMARY KEY, value TEXT NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Tenant/Company-specific overrides CREATE TABLE IF NOT EXISTS company_settings ( company_id BIGINT NOT NULL REFERENCES companies (id) ON DELETE CASCADE, key TEXT NOT NULL, value TEXT NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (company_id, key) ); CREATE TABLE user_bonuses ( id BIGSERIAL PRIMARY KEY, name TEXT NOT NULL, description TEXT NOT NULL, type TEXT NOT NULL, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, reward_amount BIGINT NOT NULL, is_claimed BOOLEAN NOT NULL DEFAULT false, expires_at TIMESTAMP NOT NULL, claimed_at TIMESTAMP, created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE flags ( id BIGSERIAL PRIMARY KEY, bet_id BIGINT REFERENCES bets (id) ON DELETE CASCADE, odds_market_id BIGINT REFERENCES odds_market (id), reason TEXT, flagged_at TIMESTAMP DEFAULT NOW (), resolved BOOLEAN DEFAULT FALSE, -- either bet or odd is flagged (not at the same time) CHECK ( ( bet_id IS NOT NULL AND odds_market_id IS NULL ) OR ( bet_id IS NULL AND odds_market_id IS NOT NULL ) ) ); CREATE TABLE direct_deposits ( id BIGSERIAL PRIMARY KEY, customer_id BIGINT REFERENCES users(id), wallet_id BIGINT REFERENCES wallets(id), bank_name TEXT, account_number TEXT, account_holder TEXT, amount NUMERIC(18,2), reference_number TEXT, transfer_screenshot TEXT, status TEXT CHECK(status IN ('PENDING', 'APPROVED', 'REJECTED')), created_at TIMESTAMPTZ, approved_by BIGINT NULL REFERENCES users(id), approved_at TIMESTAMPTZ NULL, rejection_reason TEXT NULL ); -- CREATE INDEX idx_direct_deposits_status ON direct_deposits (status); -- CREATE INDEX idx_direct_deposits_customer ON direct_deposits (customer_id); -- CREATE INDEX idx_direct_deposits_reference ON direct_deposits (bank_reference); CREATE TABLE IF NOT EXISTS raffles ( id SERIAL PRIMARY KEY, company_id INT NOT NULL, name VARCHAR(255) NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT NOW(), expires_at TIMESTAMP NOT NULL, -- -1 means there is no limit for the raffle ticket_limit INT NOT NULL DEFAULT -1, type VARCHAR(50) NOT NULL CHECK (type IN ('virtual', 'sport')), status VARCHAR(50) NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'completed')) ); CREATE TABLE IF NOT EXISTS raffle_tickets ( id SERIAL PRIMARY KEY, raffle_id INT NOT NULL REFERENCES raffles(id) ON DELETE CASCADE, user_id INT NOT NULL, is_active BOOL DEFAULT true ); CREATE TABLE IF NOT EXISTS raffle_winners ( id SERIAL PRIMARY KEY, raffle_id INT NOT NULL REFERENCES raffles(id) ON DELETE CASCADE, user_id INT NOT NULL, rank INT NOT NULL, created_at TIMESTAMP NOT NULL DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS raffle_sport_filters ( id SERIAL PRIMARY KEY, raffle_id INT NOT NULL REFERENCES raffles(id) ON DELETE CASCADE, sport_id BIGINT NOT NULL, league_id BIGINT NOT NULL, CONSTRAINT unique_raffle_sport_league UNIQUE (raffle_id, sport_id, league_id) ); CREATE TABLE IF NOT EXISTS raffle_game_filters ( id SERIAL PRIMARY KEY, raffle_id INT NOT NULL REFERENCES raffles(id) ON DELETE CASCADE, game_id VARCHAR(150) NOT NULL, CONSTRAINT unique_raffle_game UNIQUE (raffle_id, game_id) ); CREATE TABLE IF NOT EXISTS company_accumulator ( id SERIAL PRIMARY KEY, company_id BIGINT NOT NULL, outcome_count BIGINT NOT NULL, multiplier REAL NOT NULL ); CREATE TABLE report_requests ( id BIGSERIAL PRIMARY KEY, company_id BIGINT, requested_by BIGINT, file_path TEXT, type TEXT NOT NULL, status TEXT NOT NULL DEFAULT 'pending', metadata JSONB NOT NULL, reject_reason TEXT, created_at TIMESTAMP DEFAULT now(), completed_at TIMESTAMP ); ------ Views CREATE VIEW companies_details AS SELECT companies.*, wallets.balance, wallets.is_active as wallet_is_active, users.first_name AS admin_first_name, users.last_name AS admin_last_name, users.phone_number AS admin_phone_number, COALESCE(cs.total_bets, 0) AS total_bets, COALESCE(cs.total_stake, 0) AS total_stake, COALESCE(cs.deducted_stake, 0) AS deducted_stake, COALESCE(cs.total_cash_out, 0) AS total_cash_out, COALESCE(cs.total_cash_backs, 0) AS total_cash_backs, COALESCE(cs.number_of_unsettled, 0) AS number_of_unsettled, COALESCE(cs.total_unsettled_amount, 0) AS total_unsettled_amount, COALESCE(cs.total_admins, 0) AS total_admins, COALESCE(cs.total_managers, 0) AS total_managers, COALESCE(cs.total_cashiers, 0) AS total_cashiers, COALESCE(cs.total_customers, 0) AS total_customers, COALESCE(cs.total_approvers, 0) AS total_approvers, COALESCE(cs.total_branches, 0) AS total_branches, cs.updated_at AS stats_updated_at FROM companies JOIN wallets ON wallets.id = companies.wallet_id JOIN users ON users.id = companies.admin_id LEFT JOIN LATERAL ( SELECT * FROM company_stats s WHERE s.company_id = companies.id ORDER BY s.interval_start DESC LIMIT 1 ) cs ON true; CREATE VIEW branch_details AS SELECT branches.*, CONCAT (users.first_name, ' ', users.last_name) AS manager_name, users.phone_number AS manager_phone_number, wallets.balance, wallets.is_active AS wallet_is_active, companies.name AS company_name, COALESCE(bs.total_bets, 0) AS total_bets, COALESCE(bs.total_stake, 0) AS total_stake, COALESCE(bs.deducted_stake, 0) AS deducted_stake, COALESCE(bs.total_cash_out, 0) AS total_cash_out, COALESCE(bs.total_cash_backs, 0) AS total_cash_backs, COALESCE(bs.number_of_unsettled, 0) AS number_of_unsettled, COALESCE(bs.total_unsettled_amount, 0) AS total_unsettled_amount, COALESCE(bs.total_cashiers, 0) AS total_cashiers, bs.updated_at AS stats_updated_at FROM branches LEFT JOIN users ON branches.branch_manager_id = users.id LEFT JOIN wallets ON wallets.id = branches.wallet_id JOIN companies ON companies.id = branches.company_id LEFT JOIN LATERAL ( SELECT * FROM branch_stats s WHERE s.branch_id = branches.id ORDER BY s.interval_start DESC LIMIT 1 ) bs ON true; CREATE TABLE IF NOT EXISTS supported_operations ( id BIGSERIAL PRIMARY KEY, name VARCHAR(255) NOT NULL, description VARCHAR(255) NOT NULL ); CREATE VIEW bet_with_outcomes AS SELECT bets.*, CONCAT (users.first_name, ' ', users.last_name) AS full_name, users.phone_number, JSON_AGG (bet_outcomes.*) AS outcomes, companies.slug as company_slug FROM bets LEFT JOIN bet_outcomes ON bets.id = bet_outcomes.bet_id LEFT JOIN users ON bets.user_id = users.id JOIN companies ON bets.company_id = companies.id GROUP BY bets.id, users.first_name, users.last_name, users.phone_number, companies.slug; CREATE VIEW ticket_with_outcomes AS SELECT tickets.*, JSON_AGG (ticket_outcomes.*) AS outcomes FROM tickets LEFT JOIN ticket_outcomes ON tickets.id = ticket_outcomes.ticket_id GROUP BY tickets.id; CREATE VIEW customer_wallet_details AS SELECT cw.id, cw.customer_id, rw.id AS regular_id, rw.balance AS regular_balance, sw.id AS static_id, sw.balance AS static_balance, rw.is_active as regular_is_active, sw.is_active as static_is_active, rw.updated_at as regular_updated_at, sw.updated_at as static_updated_at, cw.created_at, users.first_name, users.last_name, users.phone_number, COALESCE(cs.number_of_transactions, 0) AS number_of_transactions, COALESCE(cs.total_transactions, 0) AS total_transactions, COALESCE(cs.number_of_deposits, 0) AS number_of_deposits, COALESCE(cs.total_deposits_amount, 0) AS total_deposits_amount, COALESCE(cs.number_of_withdraws, 0) AS number_of_withdraws, COALESCE(cs.total_withdraws_amount, 0) AS total_withdraws_amount, COALESCE(cs.number_of_transfers, 0) AS number_of_transfers, COALESCE(cs.total_transfers_amount, 0) AS total_transfers_amount, cs.updated_at AS stats_updated_at FROM customer_wallets cw JOIN wallets rw ON cw.regular_wallet_id = rw.id JOIN wallets sw ON cw.static_wallet_id = sw.id JOIN users ON users.id = cw.customer_id LEFT JOIN LATERAL ( SELECT * FROM wallet_stats s WHERE s.wallet_id = cw.regular_wallet_id ORDER BY s.interval_start DESC LIMIT 1 ) cs ON true; CREATE VIEW wallet_transfer_details AS SELECT wt.*, users.first_name, users.last_name, users.phone_number FROM wallet_transfer wt LEFT JOIN users ON users.id = wt.cashier_id; CREATE VIEW shop_transaction_detail AS SELECT st.*, cr.first_name AS creator_first_name, cr.last_name AS creator_last_name, cr.phone_number AS creator_phone_number, ap.first_name AS approver_first_name, ap.last_name AS approver_last_name, ap.phone_number AS approver_phone_number, branches.name AS branch_name, branches.location AS branch_location FROM shop_transactions st LEFT JOIN users cr ON cr.id = st.user_id LEFT JOIN users ap ON ap.id = st.approved_by LEFT JOIN branches ON branches.id = st.branch_id; CREATE VIEW shop_bet_detail AS SELECT sb.*, st.full_name AS customer_full_name, st.phone_number AS customer_phone_number, st.branch_id, st.company_id, st.amount, st.verified AS transaction_verified, bets.status, bets.total_odds, bets.fast_code, JSON_AGG (bet_outcomes.*) AS outcomes FROM shop_bets AS sb JOIN shop_transactions st ON st.id = sb.shop_transaction_id JOIN bets ON bets.id = sb.bet_id LEFT JOIN bet_outcomes ON bet_outcomes.bet_id = sb.bet_id GROUP BY sb.id, st.full_name, st.phone_number, st.branch_id, st.company_id, st.amount, st.verified, bets.status, bets.total_odds, bets.fast_code; CREATE VIEW shop_deposit_detail AS SELECT sd.*, st.full_name, st.phone_number, st.branch_id, st.company_id, st.amount, st.verified AS transaction_verified FROM shop_deposits AS sd JOIN shop_transactions st ON st.id = sd.shop_transaction_id; CREATE OR REPLACE VIEW event_detailed AS SELECT events.*, leagues.country_code as league_cc, COALESCE(om.total_outcomes, 0) AS total_outcomes, COALESCE(ebs.number_of_bets, 0) AS number_of_bets, COALESCE(ebs.total_amount, 0) AS total_amount, COALESCE(ebs.avg_bet_amount, 0) AS avg_bet_amount, COALESCE(ebs.total_potential_winnings, 0) AS total_potential_winnings FROM events LEFT JOIN event_bet_stats ebs ON ebs.event_id = events.id LEFT JOIN leagues ON leagues.id = events.league_id LEFT JOIN ( SELECT event_id, SUM(number_of_outcomes) AS total_outcomes FROM odds_market GROUP BY event_id ) om ON om.event_id = events.id; CREATE VIEW odds_market_with_event AS SELECT o.*, e.is_monitored, e.is_live, e.status, e.source FROM odds_market o JOIN events e ON o.event_id = e.id; -- Views only for SQLC to generate structs for them (so that we can reuse those structs) CREATE VIEW league_with_settings AS SELECT l.*, cls.company_id, COALESCE(cls.is_active, l.default_is_active) AS is_active, COALESCE(cls.is_featured, l.default_is_featured) AS is_featured, cls.updated_at FROM leagues l LEFT JOIN company_league_settings cls ON l.id = cls.league_id; CREATE VIEW event_with_settings AS SELECT e.*, ces.company_id, COALESCE(ces.is_active, e.default_is_active) AS is_active, COALESCE(ces.is_featured, e.default_is_featured) AS is_featured, COALESCE( ces.winning_upper_limit, e.default_winning_upper_limit ) AS winning_upper_limit, ces.updated_at as company_updated_at, l.country_code as league_cc, COALESCE(om.total_outcomes, 0) AS total_outcomes, COALESCE(ebs.number_of_bets, 0) AS number_of_bets, COALESCE(ebs.total_amount, 0) AS total_amount, COALESCE(ebs.avg_bet_amount, 0) AS avg_bet_amount, COALESCE(ebs.total_potential_winnings, 0) AS total_potential_winnings FROM events e LEFT JOIN company_event_settings ces ON e.id = ces.event_id JOIN leagues l ON l.id = e.league_id LEFT JOIN event_bet_stats ebs ON ebs.event_id = e.id LEFT JOIN ( SELECT event_id, SUM(number_of_outcomes) AS total_outcomes FROM odds_market GROUP BY event_id ) om ON om.event_id = e.id; CREATE VIEW odds_market_with_settings AS SELECT o.id, o.event_id, o.market_type, o.market_name, o.market_category, o.market_id, o.number_of_outcomes, o.default_is_active, o.fetched_at, o.expires_at, cos.company_id, COALESCE(cos.is_active, o.default_is_active) AS is_active, COALESCE(cms.is_active, TRUE) AS is_market_active, COALESCE(cos.custom_raw_odds, o.raw_odds) AS raw_odds, cos.updated_at FROM odds_market o LEFT JOIN company_odd_settings cos ON o.id = cos.odds_market_id LEFT JOIN company_odd_market_settings cms ON o.id = cms.market_id; CREATE VIEW report_request_detail AS SELECT r.*, c.name AS company_name, c.slug AS company_slug, u.first_name AS requester_first_name, u.last_name AS requester_last_name, u.role AS requester_role FROM report_requests r LEFT JOIN companies c ON c.id = r.company_id LEFT JOIN users u ON u.id = r.requested_by; -- Foreign Keys ALTER TABLE refresh_tokens ADD CONSTRAINT fk_refresh_tokens_users FOREIGN KEY (user_id) REFERENCES users (id); ALTER TABLE bets ADD CONSTRAINT fk_bets_users FOREIGN KEY (user_id) REFERENCES users (id); ALTER TABLE wallets ADD CONSTRAINT fk_wallets_users FOREIGN KEY (user_id) REFERENCES users (id); ALTER TABLE customer_wallets ADD CONSTRAINT fk_customer_wallets_customers FOREIGN KEY (customer_id) REFERENCES users (id), ADD CONSTRAINT fk_customer_wallets_regular_wallet FOREIGN KEY (regular_wallet_id) REFERENCES wallets (id), ADD CONSTRAINT fk_customer_wallets_static_wallet FOREIGN KEY (static_wallet_id) REFERENCES wallets (id); ALTER TABLE wallet_transfer ADD CONSTRAINT fk_wallet_transfer_receiver_wallet FOREIGN KEY (receiver_wallet_id) REFERENCES wallets (id), ADD CONSTRAINT fk_wallet_transfer_sender_wallet FOREIGN KEY (sender_wallet_id) REFERENCES wallets (id), ADD CONSTRAINT fk_wallet_transfer_cashier FOREIGN KEY (cashier_id) REFERENCES users (id); ALTER TABLE shop_transactions ADD CONSTRAINT fk_shop_transactions_branches FOREIGN KEY (branch_id) REFERENCES branches (id), ADD CONSTRAINT fk_shop_transactions_users FOREIGN KEY (user_id) REFERENCES users (id); ALTER TABLE shop_bets ADD CONSTRAINT fk_shop_bet_transactions FOREIGN KEY (shop_transaction_id) REFERENCES shop_transactions (id), ADD CONSTRAINT fk_shop_bet_bets FOREIGN KEY (bet_id) REFERENCES bets (id); ALTER TABLE shop_deposits ADD CONSTRAINT fk_shop_deposit_transactions FOREIGN KEY (shop_transaction_id) REFERENCES shop_transactions (id), ADD CONSTRAINT fk_shop_deposit_customers FOREIGN KEY (customer_id) REFERENCES users (id); ALTER TABLE branches ADD CONSTRAINT fk_branches_wallet FOREIGN KEY (wallet_id) REFERENCES wallets (id), ADD CONSTRAINT fk_branches_manager FOREIGN KEY (branch_manager_id) REFERENCES users (id), ADD CONSTRAINT fk_branches_location FOREIGN KEY (location) REFERENCES branch_locations (key); ALTER TABLE branch_operations ADD CONSTRAINT fk_branch_operations_operations FOREIGN KEY (operation_id) REFERENCES supported_operations (id) ON DELETE CASCADE, ADD CONSTRAINT fk_branch_operations_branches FOREIGN KEY (branch_id) REFERENCES branches (id) ON DELETE CASCADE; ALTER TABLE branch_cashiers ADD CONSTRAINT fk_branch_cashiers_users FOREIGN KEY (user_id) REFERENCES users (id) ON DELETE CASCADE, ADD CONSTRAINT fk_branch_cashiers_branches FOREIGN KEY (branch_id) REFERENCES branches (id) ON DELETE CASCADE; ALTER TABLE companies ADD CONSTRAINT fk_companies_admin FOREIGN KEY (admin_id) REFERENCES users (id), ADD CONSTRAINT fk_companies_wallet FOREIGN KEY (wallet_id) REFERENCES wallets (id) ON DELETE CASCADE; ALTER TABLE company_league_settings ADD CONSTRAINT fk_league_settings_company FOREIGN KEY (company_id) REFERENCES companies (id) ON DELETE CASCADE, ADD CONSTRAINT fk_league_settings_league FOREIGN KEY (league_id) REFERENCES leagues (id) ON DELETE CASCADE; ALTER TABLE company_event_settings ADD CONSTRAINT fk_event_settings_company FOREIGN KEY (company_id) REFERENCES companies (id) ON DELETE CASCADE, ADD CONSTRAINT fk_event_settings_event FOREIGN KEY (event_id) REFERENCES events (id) ON DELETE CASCADE; ALTER TABLE company_odd_settings ADD CONSTRAINT fk_odds_settings_company FOREIGN KEY (company_id) REFERENCES companies (id) ON DELETE CASCADE, ADD CONSTRAINT fk_odds_settings_odds_market FOREIGN KEY (odds_market_id) REFERENCES odds_market (id) ON DELETE CASCADE;