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 ) ); 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, amount BIGINT NOT NULL, total_odds REAL NOT NULL, status INT NOT NULL, full_name VARCHAR(255) NOT NULL, phone_number VARCHAR(255) NOT NULL, branch_id BIGINT, user_id BIGINT, cashed_out BOOLEAN DEFAULT FALSE NOT NULL, cashout_id VARCHAR(255) NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, is_shop_bet BOOLEAN NOT NULL, UNIQUE(cashout_id), CHECK ( user_id IS NOT NULL OR branch_id IS NOT NULL ) ); CREATE TABLE IF NOT EXISTS tickets ( id BIGSERIAL PRIMARY KEY, amount BIGINT NOT NULL, total_odds REAL NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); 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 VARCHAR(255) NOT NULL, away_team_name VARCHAR(255) NOT NULL, market_id BIGINT NOT NULL, market_name VARCHAR(255) NOT NULL, odd REAL NOT NULL, odd_name VARCHAR(255) NOT NULL, odd_header VARCHAR(255) NOT NULL, odd_handicap VARCHAR(255) 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 VARCHAR(255) NOT NULL, away_team_name VARCHAR(255) NOT NULL, market_id BIGINT NOT NULL, market_name VARCHAR(255) NOT NULL, odd REAL NOT NULL, odd_name VARCHAR(255) NOT NULL, odd_header VARCHAR(255) NOT NULL, odd_handicap VARCHAR(255) NOT NULL, status INT NOT NULL DEFAULT 0, expires TIMESTAMP NOT NULL ); 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, is_active BOOLEAN NOT NULL DEFAULT true, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); 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 NOT NULL, type VARCHAR(255) NOT NULL, receiver_wallet_id BIGINT NOT NULL, sender_wallet_id BIGINT, cashier_id BIGINT, verified BOOLEAN NOT NULL DEFAULT false, payment_method VARCHAR(255) NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS transactions ( id BIGSERIAL PRIMARY KEY, amount BIGINT NOT NULL, branch_id BIGINT NOT NULL, company_id BIGINT NOT NULL, cashier_id BIGINT NOT NULL, cashier_name VARCHAR(255) NOT NULL, bet_id BIGINT NOT NULL, number_of_outcomes BIGINT NOT NULL, type BIGINT NOT NULL, payment_option BIGINT NOT NULL, full_name VARCHAR(255) NOT NULL, phone_number VARCHAR(255) NOT NULL, bank_code VARCHAR(255) NOT NULL, beneficiary_name VARCHAR(255) NOT NULL, account_name VARCHAR(255) NOT NULL, account_number VARCHAR(255) NOT NULL, reference_number VARCHAR(255) NOT NULL, verified BOOLEAN NOT NULL DEFAULT false, approved_by BIGINT, approver_name VARCHAR(255), branch_location VARCHAR(255) NOT NULL, branch_name VARCHAR(255) NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS branches ( id BIGSERIAL PRIMARY KEY, name VARCHAR(255) NOT NULL, location VARCHAR(255) NOT NULL, 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 ); 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 events ( id TEXT PRIMARY KEY, sport_id TEXT, match_name TEXT, home_team TEXT, away_team TEXT, home_team_id TEXT, away_team_id TEXT, home_kit_image TEXT, away_kit_image TEXT, league_id TEXT, league_name TEXT, league_cc TEXT, start_time TIMESTAMP, score TEXT, match_minute INT, timer_status TEXT, added_time INT, match_period INT, is_live BOOLEAN, status TEXT, fetched_at TIMESTAMP DEFAULT now(), source TEXT DEFAULT 'b365api' ); CREATE TABLE odds ( id SERIAL PRIMARY KEY, event_id TEXT, fi TEXT, market_type TEXT NOT NULL, market_name TEXT, market_category TEXT, market_id TEXT, name TEXT, handicap TEXT, odds_value DOUBLE PRECISION, section TEXT NOT NULL, category TEXT, raw_odds JSONB, fetched_at TIMESTAMP DEFAULT now(), source TEXT DEFAULT 'b365api', is_active BOOLEAN DEFAULT true, UNIQUE (market_id, name, handicap), UNIQUE (event_id, market_id, name, handicap), UNIQUE (event_id, market_id) ); CREATE TABLE companies ( id BIGSERIAL PRIMARY KEY, name TEXT NOT NULL, admin_id BIGINT NOT NULL, wallet_id BIGINT NOT NULL ); -- Views CREATE VIEW companies_details AS SELECT companies.*, wallets.balance, wallets.is_active, users.first_name AS admin_first_name, users.last_name AS admin_last_name, users.phone_number AS admin_phone_number FROM companies JOIN wallets ON wallets.id = companies.wallet_id JOIN users ON users.id = companies.admin_id; ; CREATE VIEW branch_details AS SELECT branches.*, CONCAT(users.first_name, ' ', users.last_name) AS manager_name, users.phone_number AS manager_phone_number FROM branches LEFT JOIN users ON branches.branch_manager_id = users.id; 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.*, JSON_AGG(bet_outcomes.*) AS outcomes FROM bets LEFT JOIN bet_outcomes ON bets.id = bet_outcomes.bet_id GROUP BY bets.id; 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; -- 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), ADD CONSTRAINT fk_bets_branches FOREIGN KEY (branch_id) REFERENCES branches(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 transactions ADD CONSTRAINT fk_transactions_branches FOREIGN KEY (branch_id) REFERENCES branches(id), ADD CONSTRAINT fk_transactions_cashiers FOREIGN KEY (cashier_id) REFERENCES users(id), ADD CONSTRAINT fk_transactions_bets FOREIGN KEY (bet_id) REFERENCES bets(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); 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; ----------------------------------------------seed data------------------------------------------------------------- -------------------------------------- DO NOT USE IN PRODUCTION------------------------------------------------- CREATE EXTENSION IF NOT EXISTS pgcrypto; INSERT INTO users ( first_name, last_name, email, phone_number, password, role, email_verified, phone_verified, created_at, updated_at, suspended_at, suspended ) VALUES ( 'John', 'Doe', 'john.doe@example.com', NULL, crypt('password123', gen_salt('bf'))::bytea, 'customer', TRUE, FALSE, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP, NULL, FALSE ); INSERT INTO users ( first_name, last_name, email, phone_number, password, role, email_verified, phone_verified, created_at, updated_at, suspended_at, suspended ) VALUES ( 'Test', 'Admin', 'test.admin@gmail.com', '0988554466', crypt('password123', gen_salt('bf'))::bytea, 'admin', TRUE, TRUE, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP, NULL, FALSE ); INSERT INTO users ( first_name, last_name, email, phone_number, password, role, email_verified, phone_verified, created_at, updated_at, suspended_at, suspended ) VALUES ( 'Samuel', 'Tariku', 'cybersamt@gmail.com', '0911111111', crypt('password@123', gen_salt('bf'))::bytea, 'super_admin', TRUE, TRUE, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP, NULL, FALSE ); INSERT INTO users ( first_name, last_name, email, phone_number, password, role, email_verified, phone_verified, created_at, updated_at, suspended_at, suspended ) VALUES ( 'Kirubel', 'Kibru', 'kirubeljkl679 @gmail.com', '0911554486', crypt('password@123', gen_salt('bf'))::bytea, 'super_admin', TRUE, TRUE, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP, NULL, FALSE ); INSERT INTO supported_operations (name, description) VALUES ('SportBook', 'Sportbook operations'), ('Virtual', 'Virtual operations'); INSERT INTO wallets ( balance, is_withdraw, is_bettable, is_transferable, user_id, is_active, created_at, updated_at ) VALUES ( 10000, TRUE, TRUE, TRUE, 1, TRUE, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP ); INSERT INTO companies ( name, admin_id, wallet_id ) values ( 'Test Company', 2, 1 ); INSERT INTO wallets ( balance, is_withdraw, is_bettable, is_transferable, user_id, is_active, created_at, updated_at ) VALUES ( 10000, TRUE, TRUE, TRUE, 2, TRUE, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP ); INSERT INTO branches ( name, location, wallet_id, branch_manager_id, company_id, is_self_owned, created_at, updated_at ) values ( 'Test Branch', 'Addis Ababa', 2, 2, 1, TRUE, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP );