-- ===================================================== -- CLASH ROYALE DISCORD BOT - DATABASE SCHEMA -- ===================================================== -- Clean schema without special characters -- ===================================================== -- Drop existing tables if they exist DROP TABLE IF EXISTS trophy_history; DROP TABLE IF EXISTS user_profiles; DROP TABLE IF EXISTS bot_settings; -- ===================================================== -- TABLE: user_profiles -- ===================================================== CREATE TABLE user_profiles ( id INTEGER PRIMARY KEY AUTOINCREMENT, discord_id TEXT UNIQUE NOT NULL, clash_tag TEXT UNIQUE NOT NULL, clash_name TEXT NOT NULL, current_trophies INTEGER DEFAULT 0, highest_trophies INTEGER DEFAULT 0, level INTEGER DEFAULT 1, clan_name TEXT, clan_tag TEXT, clan_role TEXT, verified BOOLEAN DEFAULT FALSE, sync_date DATETIME DEFAULT CURRENT_TIMESTAMP, last_update DATETIME DEFAULT CURRENT_TIMESTAMP, created_at DATETIME DEFAULT CURRENT_TIMESTAMP ); -- ===================================================== -- TABLE: trophy_history -- ===================================================== CREATE TABLE trophy_history ( id INTEGER PRIMARY KEY AUTOINCREMENT, user_profile_id INTEGER NOT NULL, old_trophies INTEGER NOT NULL, new_trophies INTEGER NOT NULL, trophy_gain INTEGER NOT NULL, milestone_reached INTEGER, congratulated BOOLEAN DEFAULT FALSE, recorded_at DATETIME DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (user_profile_id) REFERENCES user_profiles(id) ON DELETE CASCADE ); -- ===================================================== -- TABLE: bot_settings -- ===================================================== CREATE TABLE bot_settings ( id INTEGER PRIMARY KEY AUTOINCREMENT, setting_key TEXT UNIQUE NOT NULL, setting_value TEXT NOT NULL, description TEXT, updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ); -- ===================================================== -- INDEXES FOR PERFORMANCE -- ===================================================== CREATE INDEX idx_user_profiles_discord_id ON user_profiles(discord_id); CREATE INDEX idx_user_profiles_clash_tag ON user_profiles(clash_tag); CREATE INDEX idx_trophy_history_user_profile ON trophy_history(user_profile_id); CREATE INDEX idx_trophy_history_recorded_at ON trophy_history(recorded_at); CREATE INDEX idx_trophy_history_milestone ON trophy_history(milestone_reached); CREATE INDEX idx_bot_settings_key ON bot_settings(setting_key); -- ===================================================== -- DEFAULT BOT SETTINGS -- ===================================================== INSERT INTO bot_settings (setting_key, setting_value, description) VALUES ('last_ranking_update', '0', 'Last ranking update timestamp'), ('total_users_synced', '0', 'Total number of synced users'), ('trophy_check_enabled', 'true', 'Enable trophy milestone checking'), ('ranking_update_enabled', 'true', 'Enable automatic ranking updates'), ('congratulations_enabled', 'true', 'Enable automatic congratulations'), ('bot_version', '1.0.0', 'Current bot version'), ('maintenance_mode', 'false', 'Bot maintenance mode'); -- ===================================================== -- USEFUL VIEWS -- ===================================================== CREATE VIEW ranking_view AS SELECT up.discord_id, up.clash_name, up.current_trophies, up.highest_trophies, up.level, up.clan_name, up.clan_role, ROW_NUMBER() OVER (ORDER BY up.current_trophies DESC) as rank_position FROM user_profiles up WHERE up.verified = 1 ORDER BY up.current_trophies DESC; CREATE VIEW recent_trophy_gains AS SELECT up.discord_id, up.clash_name, th.old_trophies, th.new_trophies, th.trophy_gain, th.milestone_reached, th.congratulated, th.recorded_at FROM trophy_history th JOIN user_profiles up ON th.user_profile_id = up.id WHERE th.recorded_at >= datetime('now', '-1 day') AND th.trophy_gain > 0 ORDER BY th.recorded_at DESC; -- ===================================================== -- TRIGGERS -- ===================================================== CREATE TRIGGER update_user_profiles_timestamp AFTER UPDATE ON user_profiles BEGIN UPDATE user_profiles SET last_update = CURRENT_TIMESTAMP WHERE id = NEW.id; END; CREATE TRIGGER update_bot_settings_timestamp AFTER UPDATE ON bot_settings BEGIN UPDATE bot_settings SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id; END;