-- 0001_initial.up.sql -- Engine/charset notes: -- - InnoDB for FK support -- - utf8mb4 for full Unicode -- Booleans are TINYINT(1). Dates use DATE/DATETIME/TIMESTAMP as appropriate. -- USERS CREATE TABLE IF NOT EXISTS users ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, username VARCHAR(191) NOT NULL UNIQUE, email VARCHAR(255) NOT NULL UNIQUE, password_hash VARCHAR(255) NOT NULL, is_admin TINYINT(1) NOT NULL DEFAULT 0, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP(), updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP() ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; CREATE TABLE audit_registration ( id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, user_id BIGINT UNSIGNED NOT NULL, username VARCHAR(255) NOT NULL, email VARCHAR(255) NOT NULL, ip VARCHAR(45) NOT NULL, user_agent VARCHAR(500), timestamp DATETIME NOT NULL, INDEX (user_id), CONSTRAINT fk_audit_registration_users FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE ); -- THUNDERBALL RESULTS CREATE TABLE IF NOT EXISTS results_thunderball ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, draw_date DATE NOT NULL UNIQUE, draw_id BIGINT UNSIGNED NOT NULL UNIQUE, machine VARCHAR(50), ballset VARCHAR(50), ball1 TINYINT UNSIGNED, ball2 TINYINT UNSIGNED, ball3 TINYINT UNSIGNED, ball4 TINYINT UNSIGNED, ball5 TINYINT UNSIGNED, thunderball TINYINT UNSIGNED ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- THUNDERBALL PRIZES CREATE TABLE IF NOT EXISTS prizes_thunderball ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, draw_id BIGINT UNSIGNED NOT NULL, draw_date DATE, prize1 VARCHAR(50), prize1_winners INT UNSIGNED, prize1_per_winner INT UNSIGNED, prize1_fund BIGINT UNSIGNED, prize2 VARCHAR(50), prize2_winners INT UNSIGNED, prize2_per_winner INT UNSIGNED, prize2_fund BIGINT UNSIGNED, prize3 VARCHAR(50), prize3_winners INT UNSIGNED, prize3_per_winner INT UNSIGNED, prize3_fund BIGINT UNSIGNED, prize4 VARCHAR(50), prize4_winners INT UNSIGNED, prize4_per_winner INT UNSIGNED, prize4_fund BIGINT UNSIGNED, prize5 VARCHAR(50), prize5_winners INT UNSIGNED, prize5_per_winner INT UNSIGNED, prize5_fund BIGINT UNSIGNED, prize6 VARCHAR(50), prize6_winners INT UNSIGNED, prize6_per_winner INT UNSIGNED, prize6_fund BIGINT UNSIGNED, prize7 VARCHAR(50), prize7_winners INT UNSIGNED, prize7_per_winner INT UNSIGNED, prize7_fund BIGINT UNSIGNED, prize8 VARCHAR(50), prize8_winners INT UNSIGNED, prize8_per_winner INT UNSIGNED, prize8_fund BIGINT UNSIGNED, prize9 VARCHAR(50), prize9_winners INT UNSIGNED, prize9_per_winner INT UNSIGNED, prize9_fund BIGINT UNSIGNED, total_winners INT UNSIGNED, total_prize_fund BIGINT UNSIGNED, CONSTRAINT fk_prizes_tb_drawdate FOREIGN KEY (draw_date) REFERENCES results_thunderball(draw_date) ON UPDATE CASCADE ON DELETE RESTRICT ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- LOTTO RESULTS CREATE TABLE IF NOT EXISTS results_lotto ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, draw_date DATE NOT NULL UNIQUE, draw_id BIGINT UNSIGNED NOT NULL UNIQUE, machine VARCHAR(50), ballset VARCHAR(50), ball1 TINYINT UNSIGNED, ball2 TINYINT UNSIGNED, ball3 TINYINT UNSIGNED, ball4 TINYINT UNSIGNED, ball5 TINYINT UNSIGNED, ball6 TINYINT UNSIGNED, bonusball TINYINT UNSIGNED ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- MY TICKETS CREATE TABLE IF NOT EXISTS my_tickets ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, userId BIGINT UNSIGNED NOT NULL, game_type VARCHAR(32) NOT NULL, draw_date DATE NOT NULL, ball1 TINYINT UNSIGNED, ball2 TINYINT UNSIGNED, ball3 TINYINT UNSIGNED, ball4 TINYINT UNSIGNED, ball5 TINYINT UNSIGNED, ball6 TINYINT UNSIGNED, bonus1 TINYINT UNSIGNED, bonus2 TINYINT UNSIGNED, duplicate TINYINT(1) NOT NULL DEFAULT 0, purchase_date DATETIME, purchase_method VARCHAR(50), image_path VARCHAR(255), created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, matched_main TINYINT UNSIGNED, matched_bonus TINYINT UNSIGNED, prize_tier VARCHAR(50), is_winner TINYINT(1) NOT NULL DEFAULT 0, prize_amount BIGINT, prize_label VARCHAR(100), syndicate_id BIGINT UNSIGNED, CONSTRAINT fk_my_tickets_user FOREIGN KEY (userId) REFERENCES users(id) ON UPDATE CASCADE ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- USERS MESSAGES CREATE TABLE IF NOT EXISTS users_messages ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, senderId BIGINT UNSIGNED NOT NULL, recipientId BIGINT UNSIGNED NOT NULL, subject VARCHAR(255) NOT NULL, message MEDIUMTEXT, is_read TINYINT(1) NOT NULL DEFAULT 0, is_archived TINYINT(1) NOT NULL DEFAULT 0, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, archived_at DATETIME NULL, CONSTRAINT fk_users_messages_sender FOREIGN KEY (senderId) REFERENCES users(id) ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT fk_users_messages_recipient FOREIGN KEY (recipientId) REFERENCES users(id) ON UPDATE CASCADE ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- USERS NOTIFICATIONS CREATE TABLE IF NOT EXISTS users_notification ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, user_id BIGINT UNSIGNED NOT NULL, subject VARCHAR(255), body MEDIUMTEXT, is_read TINYINT(1) NOT NULL DEFAULT 0, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT fk_users_notification_user FOREIGN KEY (user_id) REFERENCES users(id) ON UPDATE CASCADE ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- AUDITLOG CREATE TABLE IF NOT EXISTS auditlog ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, username VARCHAR(191), success TINYINT(1), timestamp DATETIME ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- LOG: TICKET MATCHING CREATE TABLE IF NOT EXISTS log_ticket_matching ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, triggered_by VARCHAR(191), run_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, tickets_matched INT, winners_found INT, notes TEXT ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- ADMIN ACCESS LOG CREATE TABLE IF NOT EXISTS admin_access_log ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, user_id BIGINT UNSIGNED, accessed_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, path VARCHAR(255), ip VARCHAR(64), user_agent VARCHAR(255), CONSTRAINT fk_admin_access_user FOREIGN KEY (user_id) REFERENCES users(id) ON UPDATE CASCADE ON DELETE SET NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- AUDIT LOG (new) CREATE TABLE IF NOT EXISTS audit_log ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, user_id BIGINT UNSIGNED, username VARCHAR(191), action VARCHAR(191), path VARCHAR(255), ip VARCHAR(64), user_agent VARCHAR(255), timestamp DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT fk_audit_log_user FOREIGN KEY (user_id) REFERENCES users(id) ON UPDATE CASCADE ON DELETE SET NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; CREATE TABLE IF NOT EXISTS audit_login ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, user_id BIGINT UNSIGNED NULL, username VARCHAR(191) NOT NULL, success TINYINT(1) NOT NULL, ip VARCHAR(64) NOT NULL, user_agent VARCHAR(255), timestamp DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, KEY idx_audit_login_user_id (user_id), CONSTRAINT fk_audit_login_user FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE SET NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- SYNDICATES CREATE TABLE IF NOT EXISTS syndicates ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, name VARCHAR(191) NOT NULL, description TEXT, owner_id BIGINT UNSIGNED NOT NULL, join_code VARCHAR(191) UNIQUE, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT fk_syndicates_owner FOREIGN KEY (owner_id) REFERENCES users(id) ON UPDATE CASCADE ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- SYNDICATE MEMBERS CREATE TABLE IF NOT EXISTS syndicate_members ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, syndicate_id BIGINT UNSIGNED NOT NULL, user_id BIGINT UNSIGNED NOT NULL, role VARCHAR(32) NOT NULL DEFAULT 'member', status VARCHAR(32) NOT NULL DEFAULT 'active', joined_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT fk_synmem_syn FOREIGN KEY (syndicate_id) REFERENCES syndicates(id) ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT fk_synmem_user FOREIGN KEY (user_id) REFERENCES users(id) ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT uq_synmem UNIQUE (syndicate_id, user_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- SYNDICATE INVITES CREATE TABLE IF NOT EXISTS syndicate_invites ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, syndicate_id BIGINT UNSIGNED NOT NULL, invited_user_id BIGINT UNSIGNED NOT NULL, sent_by_user_id BIGINT UNSIGNED NOT NULL, status VARCHAR(32) NOT NULL DEFAULT 'pending', created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT fk_syninv_syn FOREIGN KEY (syndicate_id) REFERENCES syndicates(id) ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT fk_syninv_invited FOREIGN KEY (invited_user_id) REFERENCES users(id) ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT fk_syninv_sender FOREIGN KEY (sent_by_user_id) REFERENCES users(id) ON UPDATE CASCADE ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- SYNDICATE INVITE TOKENS CREATE TABLE IF NOT EXISTS syndicate_invite_tokens ( id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, syndicate_id BIGINT UNSIGNED NOT NULL, token VARCHAR(191) NOT NULL UNIQUE, invited_by_user_id BIGINT UNSIGNED NOT NULL, accepted_by_user_id BIGINT UNSIGNED, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, accepted_at DATETIME, expires_at DATETIME, CONSTRAINT fk_syninvtoken_syn FOREIGN KEY (syndicate_id) REFERENCES syndicates(id) ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT fk_syninvtoken_invitedby FOREIGN KEY (invited_by_user_id) REFERENCES users(id) ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT fk_syninvtoken_acceptedby FOREIGN KEY (accepted_by_user_id) REFERENCES users(id) ON UPDATE CASCADE ON DELETE SET NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;