diff --git a/data/schema.sql b/data/schema.sql index 6c794b20..26a0c607 100644 --- a/data/schema.sql +++ b/data/schema.sql @@ -17,6 +17,32 @@ $$ language 'plpgsql'; -- }}} -- App metadata {{{ +CREATE TABLE AppData( + appid TEXT PRIMARY KEY, + last_study_badge_scan TIMESTAMP +); + +CREATE TABLE AppConfig( + appid TEXT, + key TEXT, + value TEXT, + PRIMARY KEY(appid, key) +); + +CREATE TABLE global_user_blacklist( + userid BIGINT PRIMARY KEY, + ownerid BIGINT NOT NULL, + reason TEXT NOT NULL, + created_at TIMESTAMPTZ DEFAULT now() +); + +CREATE TABLE global_guild_blacklist( + guildid BIGINT PRIMARY KEY, + ownerid BIGINT NOT NULL, + reason TEXT NOT NULL, + created_at TIMESTAMPTZ DEFAULT now() +); + CREATE TABLE app_config( appname TEXT PRIMARY KEY, created_at TIMESTAMPTZ NOT NULL DEFAULT now() @@ -57,115 +83,32 @@ CREATE TABLE bot_config_presence( activity_name Text ); -CREATE TABLE AppData( - appid TEXT PRIMARY KEY, - last_study_badge_scan TIMESTAMP -); - -CREATE TABLE AppConfig( - appid TEXT, - key TEXT, - value TEXT, - PRIMARY KEY(appid, key) -); - -CREATE TABLE global_user_blacklist( - userid BIGINT PRIMARY KEY, - ownerid BIGINT NOT NULL, - reason TEXT NOT NULL, - created_at TIMESTAMPTZ DEFAULT now() -); - -CREATE TABLE global_guild_blacklist( - guildid BIGINT PRIMARY KEY, - ownerid BIGINT NOT NULL, - reason TEXT NOT NULL, - created_at TIMESTAMPTZ DEFAULT now() -); -- }}} --- Analytics data {{{ -CREATE SCHEMA "analytics"; - -CREATE TABLE analytics.snapshots( - snapshotid SERIAL PRIMARY KEY, - appname TEXT NOT NULL REFERENCES bot_config (appname), - guild_count INTEGER NOT NULL, - member_count INTEGER NOT NULL, - user_count INTEGER NOT NULL, - in_voice INTEGER NOT NULL, - created_at TIMESTAMPTZ NOT NULL DEFAULT (now() at time zone 'utc') -); - - -CREATE TABLE analytics.events( - eventid SERIAL PRIMARY KEY, - appname TEXT NOT NULL REFERENCES bot_config (appname), - ctxid BIGINT, - guildid BIGINT, - created_at TIMESTAMPTZ NOT NULL DEFAULT (now() at time zone 'utc') -); - -CREATE TYPE analytics.CommandStatus AS ENUM( - 'COMPLETED', - 'CANCELLED' - 'FAILED' -); - -CREATE TABLE analytics.commands( - cmdname TEXT NOT NULL, - cogname TEXT, - userid BIGINT NOT NULL, - status analytics.CommandStatus NOT NULL, - error TEXT, - execution_time REAL NOT NULL -) INHERITS (analytics.events); - - -CREATE TYPE analytics.GuildAction AS ENUM( - 'JOINED', - 'LEFT' -); - -CREATE TABLE analytics.guilds( - guildid BIGINT NOT NULL, - action analytics.GuildAction NOT NULL -) INHERITS (analytics.events); - - -CREATE TYPE analytics.VoiceAction AS ENUM( - 'JOINED', - 'LEFT' -); - -CREATE TABLE analytics.voice_sessions( - userid BIGINT NOT NULL, - action analytics.VoiceAction NOT NULL -) INHERITS (analytics.events); - -CREATE TABLE analytics.gui_renders( - cardname TEXT NOT NULL, - duration INTEGER NOT NULL -) INHERITS (analytics.events); ---- }}} - -- User configuration data {{{ CREATE TABLE user_config( userid BIGINT PRIMARY KEY, timezone TEXT, + name TEXT, topgg_vote_reminder BOOLEAN, avatar_hash TEXT, - name TEXT, + API_timestamp BIGINT, + gems INTEGER DEFAULT 0, first_seen TIMESTAMPTZ DEFAULT now(), last_seen TIMESTAMPTZ, - API_timestamp BIGINT, locale_hint TEXT, locale TEXT, - gems INTEGER DEFAULT 0 + show_global_stats BOOLEAN ); -- }}} -- Guild configuration data {{{ +CREATE TYPE RankType AS ENUM( + 'XP', + 'VOICE', + 'MESSAGE' +); + CREATE TABLE guild_config( guildid BIGINT PRIMARY KEY, admin_role BIGINT, @@ -201,10 +144,20 @@ CREATE TABLE guild_config( daily_study_cap INTEGER, pomodoro_channel BIGINT, name TEXT, - first_joined_at TIMESTAMPTZ DEFAULT now(), - left_at TIMESTAMPTZ, locale TEXT, - force_locale BOOLEAN + force_locale BOOLEAN, + allow_transfers BOOLEAN, + season_start TIMESTAMPTZ, + xp_per_period INTEGER, + xp_per_centiword INTEGER, + coins_per_centixp INTEGER, + timezone TEXT, + rank_type RankType, + rank_channel BIGINT, + dm_ranks BOOLEAN, + renting_visible BOOLEAN, + first_joined_at TIMESTAMPTZ DEFAULT now(), + left_at TIMESTAMPTZ ); CREATE TABLE ignored_members( @@ -236,6 +189,84 @@ CREATE TABLE bot_autoroles( roleid BIGINT NOT NULL ); CREATE INDEX bot_autoroles_guilds ON bot_autoroles (guildid); + +CREATE TYPE StatisticType AS ENUM( + 'VOICE', + 'TEXT', + 'ANKI' +); +CREATE TABLE visible_statistics( + guildid BIGINT NOT NULL REFERENCES guild_config ON DELETE CASCADE, + stat_type StatisticType NOT NULL +); +CREATE INDEX visible_statistics_guilds ON visible_statistics (guildid); + +CREATE TABLE channel_webhooks( + channelid BIGINT NOT NULL PRIMARY KEY, + webhookid BIGINT NOT NULL, + token TEXT NOT NULL +); +-- }}} + +-- Economy Data {{{ +CREATE TYPE CoinTransactionType AS ENUM( + 'REFUND', + 'TRANSFER', + 'SHOP_PURCHASE', + 'VOICE_SESSION', + 'TEXT_SESSION', + 'ADMIN', + 'TASKS', + 'SCHEDULE_BOOK', + 'SCHEDULE_REWARD', + 'OTHER' +); + + +CREATE TABLE coin_transactions( + transactionid SERIAL PRIMARY KEY, + transactiontype CoinTransactionType NOT NULL, + guildid BIGINT NOT NULL REFERENCES guild_config (guildid) ON DELETE CASCADE, + actorid BIGINT NOT NULL, + amount INTEGER NOT NULL, + bonus INTEGER NOT NULL DEFAULT 0, + from_account BIGINT, + to_account BIGINT, + refunds INTEGER REFERENCES coin_transactions (transactionid) ON DELETE SET NULL, + created_at TIMESTAMPTZ NOT NULL DEFAULT (now() at time zone 'utc') +); +CREATE INDEX coin_transaction_guilds ON coin_transactions (guildid); + +CREATE TABLE coin_transactions_tasks( + transactionid INTEGER PRIMARY KEY REFERENCES coin_transactions (transactionid) ON DELETE CASCADE, + count INTEGER NOT NULL +); + +CREATE TYPE EconAdminTarget AS ENUM( + 'ROLE', + 'USER', + 'GUILD' +); + +CREATE TYPE EconAdminAction AS ENUM( + 'SET', + 'ADD' +); + +CREATE TABLE economy_admin_actions( + actionid SERIAL PRIMARY KEY, + target_type EconAdminTarget NOT NULL, + action_type EconAdminAction NOT NULL, + targetid INTEGER NOT NULL, + amount INTEGER NOT NULL +); + +CREATE TABLE coin_transactions_admin_actions( + actionid INTEGER NOT NULL REFERENCES economy_admin_actions (actionid), + transactionid INTEGER NOT NULL REFERENCES coin_transactions (transactionid), + PRIMARY KEY (actionid, transactionid) +); +CREATE INDEX coin_transactions_admin_actions_transactionid ON coin_transactions_admin_actions (transactionid); -- }}} -- Workout data {{{ @@ -259,7 +290,7 @@ CREATE INDEX workout_sessions_members ON workout_sessions (guildid, userid); -- Tasklist data {{{ CREATE TABLE tasklist( taskid SERIAL PRIMARY KEY, - userid BIGINT NOT NULL REFERENCES user_config (userid) ON DELETE CASCADE, + userid BIGINT NOT NULL, content TEXT NOT NULL, rewarded BOOL DEFAULT FALSE, deleted_at TIMESTAMPTZ, @@ -268,31 +299,61 @@ CREATE TABLE tasklist( last_updated_at TIMESTAMPTZ ); CREATE INDEX tasklist_users ON tasklist (userid); +ALTER TABLE tasklist + ADD CONSTRAINT fk_tasklist_users + FOREIGN KEY (userid) + REFERENCES user_config (userid) + ON DELETE CASCADE + NOT VALID; +ALTER TABLE tasklist + ADD COLUMN parentid INTEGER REFERENCES tasklist (taskid) ON DELETE SET NULL; CREATE TABLE tasklist_channels( - guildid BIGINT NOT NULL REFERENCES guild_config (guildid) ON DELETE CASCADE, + guildid BIGINT NOT NULL, channelid BIGINT NOT NULL ); CREATE INDEX tasklist_channels_guilds ON tasklist_channels (guildid); +ALTER TABLE tasklist_channels + ADD CONSTRAINT fk_tasklist_channels_guilds + FOREIGN KEY (guildid) + REFERENCES guild_config (guildid) + ON DELETE CASCADE + NOT VALID; + +CREATE TABLE tasklist_reward_history( + userid BIGINT NOT NULL, + reward_time TIMESTAMP DEFAULT (now() at time zone 'utc'), + reward_count INTEGER +); +CREATE INDEX tasklist_reward_history_users ON tasklist_reward_history (userid, reward_time); -- }}} -- Reminder data {{{ CREATE TABLE reminders( - reminderid SERIAL PRIMARY KEY, - userid BIGINT NOT NULL REFERENCES user_config ON DELETE CASCADE, - remind_at TIMESTAMP NOT NULL, - content TEXT NOT NULL, - message_link TEXT, - interval INTEGER, - created_at TIMESTAMP DEFAULT (now() at time zone 'utc'), - failed BOOLEAN, - title TEXT, - footer TEXT + reminderid SERIAL PRIMARY KEY, + userid BIGINT NOT NULL REFERENCES user_config(userid) ON DELETE CASCADE, + remind_at TIMESTAMPTZ NOT NULL, + content TEXT NOT NULL, + message_link TEXT, + interval INTEGER, + failed BOOLEAN, + created_at TIMESTAMPTZ DEFAULT now(), + title TEXT, + footer TEXT ); CREATE INDEX reminder_users ON reminders (userid); -- }}} --- Study tracking data {{{ +-- Voice tracking data {{{ +CREATE TABLE tracked_channels( + channelid BIGINT PRIMARY KEY, + guildid BIGINT NOT NULL, + deleted BOOLEAN DEFAULT FALSE, + _timestamp TIMESTAMPTZ NOT NULL DEFAULT (now() AT TIME ZONE 'utc'), + FOREIGN KEY (guildid) REFERENCES guild_config (guildid) ON DELETE CASCADE +); +CREATE INDEX tracked_channels_guilds ON tracked_channels (guildid); + CREATE TABLE untracked_channels( guildid BIGINT NOT NULL, channelid BIGINT NOT NULL @@ -332,20 +393,24 @@ CREATE TABLE shop_items( ); CREATE INDEX guild_shop_items ON shop_items (guildid); +CREATE TABLE coin_transactions_shop( + transactionid INTEGER PRIMARY KEY REFERENCES coin_transactions (transactionid) ON DELETE CASCADE, + itemid INTEGER NOT NULL REFERENCES shop_items (itemid) ON DELETE CASCADE +); + CREATE TABLE shop_items_colour_roles( itemid INTEGER PRIMARY KEY REFERENCES shop_items(itemid) ON DELETE CASCADE, roleid BIGINT NOT NULL ); CREATE TABLE member_inventory( - inventoryid SERIAL PRIMARY KEY, + inventoryid SERiAL PRIMARY KEY, + transactionid INTEGER REFERENCES coin_transactions (transactionid) ON DELETE SET NULL, guildid BIGINT NOT NULL, userid BIGINT NOT NULL, - first_joined TIMESTAMPTZ DEFAULT now(), - last_left TIMESTAMPTZ, - transactionid INTEGER REFERENCES coin_transactions(transactionid) ON DELETE SET NULL, itemid INTEGER NOT NULL REFERENCES shop_items(itemid) ON DELETE CASCADE ); + CREATE INDEX member_inventory_members ON member_inventory(guildid, userid); @@ -358,6 +423,25 @@ CREATE VIEW shop_item_info AS LEFT JOIN shop_items_colour_roles USING (itemid) ORDER BY itemid ASC; + +CREATE VIEW member_inventory_info AS + SELECT + inv.inventoryid AS inventoryid, + inv.guildid AS guildid, + inv.userid AS userid, + inv.transactionid AS transactionid, + items.itemid AS itemid, + items.item_type AS item_type, + items.price AS price, + items.purchasable AS purchasable, + items.deleted AS deleted, + items.guild_itemid AS guild_itemid, + items.roleid AS roleid + FROM + member_inventory inv + LEFT JOIN shop_item_info items USING (itemid) + ORDER BY itemid ASC; + /* -- Shop config, not implemented CREATE TABLE guild_shop_config( @@ -376,6 +460,14 @@ CREATE TABLE video_channels( ); CREATE INDEX video_channels_guilds ON video_channels (guildid); +CREATE TABLE video_exempt_roles( + guildid BIGINT NOT NULL, + roleid BIGINT NOT NULL, + _timestamp TIMESTAMPTZ NOT NULL DEFAULT now(), + FOREIGN KEY (guildid) REFERENCES guild_config (guildid) ON DELETE CASCADE ON UPDATE CASCADE, + PRIMARY KEY (guildid, roleid) +); + CREATE TYPE TicketType AS ENUM ( 'NOTE', 'STUDY_BAN', @@ -517,8 +609,8 @@ CREATE INDEX studyban_durations_guilds ON studyban_durations (guildid); -- Member configuration and stored data {{{ CREATE TABLE members( - guildid BIGINT REFERENCES guild_config ON DELETE CASCADE, - userid BIGINT ON DELETE CASCADE, + guildid BIGINT, + userid BIGINT, tracked_time INTEGER DEFAULT 0, coins INTEGER DEFAULT 0, workout_count INTEGER DEFAULT 0, @@ -527,6 +619,8 @@ CREATE TABLE members( last_study_badgeid INTEGER REFERENCES study_badges ON DELETE SET NULL, video_warned BOOLEAN DEFAULT FALSE, display_name TEXT, + first_joined TIMESTAMPTZ DEFAULT now(), + last_left TIMESTAMPTZ, _timestamp TIMESTAMP DEFAULT (now() at time zone 'utc'), PRIMARY KEY(guildid, userid) ); @@ -535,6 +629,81 @@ CREATE INDEX member_timestamps ON members (_timestamp); CREATE TRIGGER update_members_timstamp BEFORE UPDATE ON members FOR EACH ROW EXECUTE PROCEDURE update_timestamp_column(); + +ALTER TABLE members + ADD CONSTRAINT fk_members_users FOREIGN KEY (userid) REFERENCES user_config (userid) ON DELETE CASCADE NOT VALID; +ALTER TABLE members + ADD CONSTRAINT fk_members_guilds FOREIGN KEY (guildid) REFERENCES guild_config (guildid) ON DELETE CASCADE NOT VALID; +-- }}} + +-- Message tracking and statistics {{{ +CREATE TYPE ExperienceType AS ENUM( + 'VOICE_XP', + 'TEXT_XP', + 'QUEST_XP', -- Custom guild quests + 'ACHIEVEMENT_XP', -- Individual tracked achievements + 'BONUS_XP' -- Manually adjusted XP +); + +CREATE TABLE member_experience( + member_expid BIGSERIAL PRIMARY KEY, + guildid BIGINT NOT NULL, + userid BIGINT NOT NULL, + earned_at TIMESTAMPTZ NOT NULL DEFAULT (now() at time zone 'UTC'), + amount INTEGER NOT NULL, + exp_type ExperienceType NOT NULL, + transactionid INTEGER REFERENCES coin_transactions ON DELETE SET NULL, + FOREIGN KEY (guildid, userid) REFERENCES members ON DELETE CASCADE +); +CREATE INDEX member_experience_members ON member_experience (guildid, userid, earned_at); +CREATE INDEX member_experience_guilds ON member_experience (guildid, earned_at); + +CREATE TABLE user_experience( + user_expid BIGSERIAL PRIMARY KEY, + userid BIGINT NOT NULL, + earned_at TIMESTAMPTZ NOT NULL DEFAULT (now() at time zone 'UTC'), + amount INTEGER NOT NULL, + exp_type ExperienceType NOT NULL, + FOREIGN KEY (userid) REFERENCES user_config ON DELETE CASCADE +); +CREATE INDEX user_experience_users ON user_experience (userid, earned_at); + + +CREATE TABLE bot_config_experience_rates( + appname TEXT PRIMARY KEY REFERENCES bot_config(appname) ON DELETE CASCADE, + period_length INTEGER, + xp_per_period INTEGER, + xp_per_centiword INTEGER +); + +CREATE TABLE text_sessions( + sessionid BIGSERIAL PRIMARY KEY, + guildid BIGINT NOT NULL, + userid BIGINT NOT NULL, + start_time TIMESTAMPTZ NOT NULL, + duration INTEGER NOT NULL, + messages INTEGER NOT NULL, + words INTEGER NOT NULL, + periods INTEGER NOT NULL, + user_expid BIGINT REFERENCES user_experience, + member_expid BIGINT REFERENCES member_experience, + end_time TIMESTAMP GENERATED ALWAYS AS + ((start_time AT TIME ZONE 'UTC') + duration * interval '1 second') + STORED, + FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) ON DELETE CASCADE +); +CREATE INDEX text_sessions_members ON text_sessions (guildid, userid); +CREATE INDEX text_sessions_start_time ON text_sessions (start_time); +CREATE INDEX text_sessions_end_time ON text_sessions (end_time); + +CREATE TABLE untracked_text_channels( + channelid BIGINT PRIMARY KEY, + guildid BIGINT NOT NULL, + _timestamp TIMESTAMPTZ NOT NULL DEFAULT (now() AT TIME ZONE 'utc'), + FOREIGN KEY (guildid) REFERENCES guild_config (guildid) ON DELETE CASCADE +); +CREATE INDEX untracked_text_channels_guilds ON untracked_text_channels (guildid); + -- }}} -- Study Session Data {{{ @@ -546,279 +715,401 @@ CREATE TYPE SessionChannelType AS ENUM ( ); -CREATE TABLE session_history( +CREATE TABLE voice_sessions( sessionid SERIAL PRIMARY KEY, guildid BIGINT NOT NULL, userid BIGINT NOT NULL, channelid BIGINT, - channel_type SessionChannelType, rating INTEGER, tag TEXT, start_time TIMESTAMPTZ NOT NULL, duration INTEGER NOT NULL, - coins_earned INTEGER NOT NULL, live_duration INTEGER DEFAULT 0, stream_duration INTEGER DEFAULT 0, video_duration INTEGER DEFAULT 0, + transactionid INTEGER REFERENCES coin_transactions (transactionid) ON UPDATE CASCADE ON DELETE CASCADE, FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) ON DELETE CASCADE ); -CREATE INDEX session_history_members ON session_history (guildid, userid, start_time); +CREATE INDEX voice_session_members ON voice_sessions (guildid, userid, start_time); +CREATE INDEX voice_session_guild_time ON voice_sessions USING BTREE (guildid, start_time); +CREATE INDEX voice_session_user_time ON voice_sessions USING BTREE (userid, start_time); +ALTER TABLE voice_sessions ADD FOREIGN KEY (channelid) REFERENCES tracked_channels (channelid); -CREATE TABLE current_sessions( +CREATE TABLE voice_sessions_ongoing( guildid BIGINT NOT NULL, userid BIGINT NOT NULL, - channelid BIGINT, - channel_type SessionChannelType, + channelid BIGINT REFERENCES tracked_channels (channelid), rating INTEGER, tag TEXT, - start_time TIMESTAMPTZ DEFAULT now(), - live_duration INTEGER DEFAULT 0, - live_start TIMESTAMPTZ, - stream_duration INTEGER DEFAULT 0, - stream_start TIMESTAMPTZ, - video_duration INTEGER DEFAULT 0, - video_start TIMESTAMPTZ, - hourly_coins INTEGER NOT NULL, - hourly_live_coins INTEGER NOT NULL, + start_time TIMESTAMPTZ DEFAULT (now() AT TIME ZONE 'UTC'), + live_duration INTEGER NOT NULL DEFAULT 0, + video_duration INTEGER NOT NULL DEFAULT 0, + stream_duration INTEGER NOT NULL DEFAULT 0, + coins_earned INTEGER NOT NULL DEFAULT 0, + last_update TIMESTAMPTZ DEFAULT (now() AT TIME ZONE 'UTC'), + live_stream BOOLEAN NOT NULL DEFAULT FALSE, + live_video BOOLEAN NOT NULL DEFAULT FALSE, + hourly_coins FLOAT NOT NULL DEFAULT 0, FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) ON DELETE CASCADE ); -CREATE UNIQUE INDEX current_session_members ON current_sessions (guildid, userid); +CREATE UNIQUE INDEX voice_sessions_ongoing_members ON voice_sessions_ongoing (guildid, userid); +CREATE FUNCTION close_study_session_at(_guildid BIGINT, _userid BIGINT, _now TIMESTAMPTZ) + RETURNS SETOF members +AS $$ + BEGIN + RETURN QUERY + WITH + voice_session AS ( + DELETE FROM voice_sessions_ongoing + WHERE guildid=_guildid AND userid=_userid + RETURNING + channelid, rating, tag, start_time, + EXTRACT(EPOCH FROM (_now - start_time)) AS total_duration, + ( + CASE WHEN live_stream + THEN stream_duration + EXTRACT(EPOCH FROM (_now - last_update)) + ELSE stream_duration + END + ) AS stream_duration, + ( + CASE WHEN live_video + THEN video_duration + EXTRACT(EPOCH FROM (_now - last_update)) + ELSE video_duration + END + ) AS video_duration, + ( + CASE WHEN live_stream OR live_video + THEN live_duration + EXTRACT(EPOCH FROM (_now - last_update)) + ELSE live_duration + END + ) AS live_duration, + ( + coins_earned + LEAST((EXTRACT(EPOCH FROM (_now - last_update)) * hourly_coins) / 3600, 2147483647) + ) AS coins_earned + ), + economy_transaction AS ( + INSERT INTO coin_transactions ( + guildid, actorid, + from_account, to_account, + amount, bonus, transactiontype + ) SELECT + _guildid, 0, + NULL, _userid, + voice_session.coins_earned, 0, 'VOICE_SESSION' + FROM voice_session + RETURNING + transactionid + ), + saved_session AS ( + INSERT INTO voice_sessions ( + guildid, userid, channelid, + rating, tag, + start_time, duration, live_duration, stream_duration, video_duration, + transactionid + ) SELECT + _guildid, _userid, voice_session.channelid, + voice_session.rating, voice_session.tag, + voice_session.start_time, voice_session.total_duration, voice_session.live_duration, + voice_session.stream_duration, voice_session.video_duration, + economy_transaction.transactionid + FROM voice_session, economy_transaction + RETURNING * + ) + UPDATE members + SET + coins=LEAST(coins::BIGINT + voice_session.coins_earned::BIGINT, 2147483647) + FROM + voice_session + WHERE + members.guildid=_guildid AND members.userid=_userid + RETURNING members.*; + END; +$$ LANGUAGE PLPGSQL; -CREATE FUNCTION study_time_since(_guildid BIGINT, _userid BIGINT, _timestamp TIMESTAMPTZ) +CREATE OR REPLACE FUNCTION update_voice_session( + _guildid BIGINT, _userid BIGINT, _at TIMESTAMPTZ, _live_stream BOOLEAN, _live_video BOOLEAN, _hourly_coins FLOAT +) RETURNS SETOF voice_sessions_ongoing AS $$ + BEGIN + RETURN QUERY + UPDATE + voice_sessions_ongoing + SET + stream_duration = ( + CASE WHEN live_stream + THEN stream_duration + EXTRACT(EPOCH FROM (_at - last_update)) + ELSE stream_duration + END + ), + video_duration = ( + CASE WHEN live_video + THEN video_duration + EXTRACT(EPOCH FROM (_at - last_update)) + ELSE video_duration + END + ), + live_duration = ( + CASE WHEN live_stream OR live_video + THEN live_duration + EXTRACT(EPOCH FROM (_at - last_update)) + ELSE live_duration + END + ), + coins_earned = ( + coins_earned + LEAST((EXTRACT(EPOCH FROM (_at - last_update)) * hourly_coins) / 3600, 2147483647) + ), + last_update = _at, + live_stream = _live_stream, + live_video = _live_video, + hourly_coins = hourly_coins + WHERE + guildid = _guildid + AND + userid = _userid + RETURNING *; + END; +$$ LANGUAGE PLPGSQL; + +-- Function to retouch session? Or handle in application? +-- Function to finish session? Or handle in application? +-- Does database function make transaction, or application? + +CREATE VIEW voice_sessions_combined AS + SELECT + userid, + guildid, + start_time, + duration, + (start_time + duration * interval '1 second') AS end_time + FROM voice_sessions + UNION ALL + SELECT + userid, + guildid, + start_time, + EXTRACT(EPOCH FROM (NOW() - start_time)) AS duration, + NOW() AS end_time + FROM voice_sessions_ongoing; + +CREATE FUNCTION study_time_between(_guildid BIGINT, _userid BIGINT, _start TIMESTAMPTZ, _end TIMESTAMPTZ) RETURNS INTEGER AS $$ BEGIN RETURN ( SELECT - SUM( - CASE - WHEN start_time >= _timestamp THEN duration - ELSE EXTRACT(EPOCH FROM (end_time - _timestamp)) - END - ) + SUM(COALESCE(EXTRACT(EPOCH FROM (upper(part) - lower(part))), 0)) FROM ( SELECT - start_time, - duration, - (start_time + duration * interval '1 second') AS end_time - FROM session_history + unnest(range_agg(tstzrange(start_time, end_time)) * multirange(tstzrange(_start, _end))) AS part + FROM voice_sessions_combined WHERE (_guildid IS NULL OR guildid=_guildid) AND userid=_userid - AND (start_time + duration * interval '1 second') >= _timestamp - UNION - SELECT - start_time, - EXTRACT(EPOCH FROM (NOW() - start_time)) AS duration, - NOW() AS end_time - FROM current_sessions - WHERE - (_guildid IS NULL OR guildid=_guildid) - AND userid=_userid - ) AS sessions + AND start_time < _end + AND end_time > _start + ) AS disjoint_parts ); END; $$ LANGUAGE PLPGSQL; - -CREATE FUNCTION close_study_session(_guildid BIGINT, _userid BIGINT) - RETURNS SETOF members +CREATE FUNCTION study_time_since(_guildid BIGINT, _userid BIGINT, _timestamp TIMESTAMPTZ) + RETURNS INTEGER AS $$ BEGIN - RETURN QUERY - WITH - current_sesh AS ( - DELETE FROM current_sessions - WHERE guildid=_guildid AND userid=_userid - RETURNING - *, - EXTRACT(EPOCH FROM (NOW() - start_time)) AS total_duration, - stream_duration + COALESCE(EXTRACT(EPOCH FROM (NOW() - stream_start)), 0) AS total_stream_duration, - video_duration + COALESCE(EXTRACT(EPOCH FROM (NOW() - video_start)), 0) AS total_video_duration, - live_duration + COALESCE(EXTRACT(EPOCH FROM (NOW() - live_start)), 0) AS total_live_duration - ), bonus_userid AS ( - SELECT COUNT(boostedTimestamp), - CASE WHEN EXISTS ( - SELECT 1 FROM Topgg - WHERE Topgg.userid=_userid AND EXTRACT(EPOCH FROM (NOW() - boostedTimestamp)) < 12.5*60*60 - ) THEN - (array_agg( - CASE WHEN boostedTimestamp <= current_sesh.start_time THEN - 1.25 - ELSE - (((current_sesh.total_duration - EXTRACT(EPOCH FROM (boostedTimestamp - current_sesh.start_time)))/current_sesh.total_duration)*0.25)+1 - END))[1] - ELSE - 1 - END - AS bonus - FROM Topgg, current_sesh - WHERE Topgg.userid=_userid AND EXTRACT(EPOCH FROM (NOW() - boostedTimestamp)) < 12.5*60*60 - ORDER BY (array_agg(boostedTimestamp))[1] DESC LIMIT 1 - ), saved_sesh AS ( - INSERT INTO session_history ( - guildid, userid, channelid, rating, tag, channel_type, start_time, - duration, stream_duration, video_duration, live_duration, - coins_earned - ) SELECT - guildid, userid, channelid, rating, tag, channel_type, start_time, - total_duration, total_stream_duration, total_video_duration, total_live_duration, - LEAST(((total_duration * hourly_coins::bigint + live_duration * hourly_live_coins::bigint) * bonus_userid.bonus )/ 3600, 2147483647) - FROM current_sesh, bonus_userid - RETURNING * - ) - UPDATE members - SET - tracked_time=(tracked_time + saved_sesh.duration), - coins=LEAST(coins::bigint + saved_sesh.coins_earned::bigint, 2147483647) - FROM saved_sesh - WHERE members.guildid=saved_sesh.guildid AND members.userid=saved_sesh.userid - RETURNING members.*; + RETURN (SELECT study_time_between(_guildid, _userid, _timestamp, NOW())); END; $$ LANGUAGE PLPGSQL; - -CREATE VIEW current_sessions_totals AS - SELECT - *, - EXTRACT(EPOCH FROM (NOW() - start_time)) AS total_duration, - stream_duration + COALESCE(EXTRACT(EPOCH FROM (NOW() - stream_start)), 0) AS total_stream_duration, - video_duration + COALESCE(EXTRACT(EPOCH FROM (NOW() - video_start)), 0) AS total_video_duration, - live_duration + COALESCE(EXTRACT(EPOCH FROM (NOW() - live_start)), 0) AS total_live_duration - FROM current_sessions; - - -CREATE VIEW members_totals AS - SELECT - *, - sesh.start_time AS session_start, - tracked_time + COALESCE(sesh.total_duration, 0) AS total_tracked_time, - coins + COALESCE((sesh.total_duration * sesh.hourly_coins + sesh.live_duration * sesh.hourly_live_coins) / 3600, 0) AS total_coins - FROM members - LEFT JOIN current_sessions_totals sesh USING (guildid, userid); - - -CREATE VIEW member_ranks AS - SELECT - *, - row_number() OVER (PARTITION BY guildid ORDER BY total_tracked_time DESC, userid ASC) AS time_rank, - row_number() OVER (PARTITION BY guildid ORDER BY total_coins DESC, userid ASC) AS coin_rank - FROM members_totals; -- }}} --- Study Badge Data {{{ -CREATE VIEW current_study_badges AS - SELECT - *, - (SELECT r.badgeid - FROM study_badges r - WHERE r.guildid = members_totals.guildid AND members_totals.total_tracked_time > r.required_time - ORDER BY r.required_time DESC - LIMIT 1) AS current_study_badgeid - FROM members_totals; +-- Activity Rank Data {{{ +CREATE TABLE xp_ranks( + rankid SERIAL PRIMARY KEY, + roleid BIGINT NOT NULL, + guildid BIGINT NOT NULL REFERENCES guild_config ON DELETE CASCADE, + required INTEGER NOT NULL, + reward INTEGER NOT NULL, + message TEXT +); +CREATE UNIQUE INDEX xp_ranks_roleid ON xp_ranks (roleid); +CREATE INDEX xp_ranks_guild_required ON xp_ranks (guildid, required); + +CREATE TABLE voice_ranks( + rankid SERIAL PRIMARY KEY, + roleid BIGINT NOT NULL, + guildid BIGINT NOT NULL REFERENCES guild_config ON DELETE CASCADE, + required INTEGER NOT NULL, + reward INTEGER NOT NULL, + message TEXT +); +CREATE UNIQUE INDEX voice_ranks_roleid ON voice_ranks (roleid); +CREATE INDEX voice_ranks_guild_required ON voice_ranks (guildid, required); + +CREATE TABLE msg_ranks( + rankid SERIAL PRIMARY KEY, + roleid BIGINT NOT NULL, + guildid BIGINT NOT NULL REFERENCES guild_config ON DELETE CASCADE, + required INTEGER NOT NULL, + reward INTEGER NOT NULL, + message TEXT +); +CREATE UNIQUE INDEX msg_ranks_roleid ON msg_ranks (roleid); +CREATE INDEX msg_ranks_guild_required ON msg_ranks (guildid, required); + +CREATE TABLE member_ranks( + guildid BIGINT NOT NULL, + userid BIGINT NOT NULL, + current_xp_rankid INTEGER REFERENCES xp_ranks ON DELETE SET NULL, + current_voice_rankid INTEGER REFERENCES voice_ranks ON DELETE SET NULL, + current_msg_rankid INTEGER REFERENCES msg_ranks ON DELETE SET NULL, + last_roleid BIGINT, + PRIMARY KEY (guildid, userid), + FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) +); + +CREATE TABLE season_stats( + guildid BIGINT NOT NULL, + userid BIGINT NOT NULL, + voice_stats INTEGER NOT NULL DEFAULT 0, + xp_stats INTEGER NOT NULL DEFAULT 0, + message_stats INTEGER NOT NULL DEFAULT 0, + season_start TIMESTAMPTZ, + updated_at TIMESTAMPTZ NOT NULL DEFAULT now(), + PRIMARY KEY (guildid, userid), + FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) +); -CREATE VIEW new_study_badges AS - SELECT - current_study_badges.* - FROM current_study_badges - WHERE - last_study_badgeid IS DISTINCT FROM current_study_badgeid - ORDER BY guildid; -- }}} -- Rented Room data {{{ -CREATE TABLE rented( +CREATE TABLE rented_rooms( channelid BIGINT PRIMARY KEY, guildid BIGINT NOT NULL, ownerid BIGINT NOT NULL, - expires_at TIMESTAMP DEFAULT ((now() at time zone 'utc') + INTERVAL '1 day'), - created_at TIMESTAMP DEFAULT (now() at time zone 'utc'), + created_at TIMESTAMPTZ DEFAULT now(), + deleted_at TIMESTAMPTZ, + coin_balance INTEGER NOT NULL DEFAULT 0, + name TEXT, + last_tick TIMESTAMPTZ, + contribution INTEGER NOT NULL DEFAULT 0, FOREIGN KEY (guildid, ownerid) REFERENCES members (guildid, userid) ON DELETE CASCADE ); -CREATE UNIQUE INDEX rented_owners ON rented (guildid, ownerid); +CREATE INDEX rented_owners ON rented_rooms(guildid, ownerid); CREATE TABLE rented_members( - channelid BIGINT NOT NULL REFERENCES rented(channelid) ON DELETE CASCADE, + channelid BIGINT NOT NULL REFERENCES rented_rooms(channelid) ON DELETE CASCADE, userid BIGINT NOT NULL ); CREATE INDEX rented_members_channels ON rented_members (channelid); CREATE INDEX rented_members_users ON rented_members (userid); -- }}} --- Accountability Rooms {{{ -CREATE TABLE accountability_slots( - slotid SERIAL PRIMARY KEY, - guildid BIGINT NOT NULL REFERENCES guild_config(guildid), - channelid BIGINT, - start_at TIMESTAMPTZ (0) NOT NULL, - messageid BIGINT, - closed_at TIMESTAMPTZ +-- Scheduled Sessions {{{ +CREATE TABLE schedule_slots( + slotid INTEGER PRIMARY KEY, + created_at TIMESTAMPTZ DEFAULT now() ); -CREATE UNIQUE INDEX slot_channels ON accountability_slots(channelid); -CREATE UNIQUE INDEX slot_guilds ON accountability_slots(guildid, start_at); -CREATE INDEX slot_times ON accountability_slots(start_at); -CREATE TABLE accountability_members( - slotid INTEGER NOT NULL REFERENCES accountability_slots(slotid) ON DELETE CASCADE, - userid BIGINT NOT NULL, - paid INTEGER NOT NULL, - duration INTEGER DEFAULT 0, - last_joined_at TIMESTAMPTZ, - PRIMARY KEY (slotid, userid) +CREATE TABLE schedule_guild_config( + guildid BIGINT PRIMARY KEY REFERENCES guild_config ON DELETE CASCADE, + schedule_cost INTEGER, + reward INTEGER, + bonus_reward INTEGER, + min_attendance INTEGER, + lobby_channel BIGINT, + room_channel BIGINT, + blacklist_after INTEGER, + blacklist_role BIGINT, + created_at TIMESTAMPTZ DEFAULT now() ); -CREATE INDEX slot_members ON accountability_members(userid); -CREATE INDEX slot_members_slotid ON accountability_members(slotid); -CREATE VIEW accountability_member_info AS - SELECT - * - FROM accountability_members - JOIN accountability_slots USING (slotid); - -CREATE VIEW accountability_open_slots AS - SELECT - * - FROM accountability_slots - WHERE closed_at IS NULL - ORDER BY start_at ASC; --- }}} - --- Reaction Roles {{{ -CREATE TABLE reaction_role_messages( - messageid BIGINT PRIMARY KEY, - guildid BIGINT NOT NULL REFERENCES guild_config (guildid) ON DELETE CASCADE, +CREATE TABLE schedule_channels( + guildid BIGINT NOT NULL REFERENCES schedule_guild_config ON DELETE CASCADE, channelid BIGINT NOT NULL, - enabled BOOLEAN DEFAULT TRUE, - required_role BIGINT, - removable BOOLEAN, - maximum INTEGER, - refunds BOOLEAN, - event_log BOOLEAN, - default_price INTEGER + PRIMARY KEY (guildid, channelid) ); -CREATE INDEX reaction_role_guilds ON reaction_role_messages (guildid); -CREATE TABLE reaction_role_reactions( - reactionid SERIAL PRIMARY KEY, - messageid BIGINT NOT NULL REFERENCES reaction_role_messages (messageid) ON DELETE CASCADE, - roleid BIGINT NOT NULL, - emoji_name TEXT, - emoji_id BIGINT, - emoji_animated BOOLEAN, - price INTEGER, - timeout INTEGER +CREATE TABLE schedule_sessions( + guildid BIGINT NOT NULL REFERENCES schedule_guild_config ON DELETE CASCADE, + slotid INTEGER NOT NULL REFERENCES schedule_slots ON DELETE CASCADE, + opened_at TIMESTAMPTZ, + closed_at TIMESTAMPTZ, + messageid BIGINT, + created_at TIMESTAMPTZ DEFAULT now(), + PRIMARY KEY (guildid, slotid) ); -CREATE INDEX reaction_role_reaction_messages ON reaction_role_reactions (messageid); -CREATE TABLE reaction_role_expiring( +CREATE TABLE schedule_session_members( guildid BIGINT NOT NULL, userid BIGINT NOT NULL, - roleid BIGINT NOT NULL, - expiry TIMESTAMPTZ NOT NULL, - reactionid INTEGER REFERENCES reaction_role_reactions (reactionid) ON DELETE SET NULL + slotid INTEGER NOT NULL, + booked_at TIMESTAMPTZ NOT NULL DEFAULT now(), + attended BOOLEAN NOT NULL DEFAULT False, + clock INTEGER NOT NULL DEFAULT 0, + book_transactionid INTEGER REFERENCES coin_transactions, + reward_transactionid INTEGER REFERENCES coin_transactions, + PRIMARY KEY (guildid, userid, slotid), + FOREIGN KEY (guildid, userid) REFERENCES members ON DELETE CASCADE, + FOREIGN KEY (guildid, slotid) REFERENCES schedule_sessions (guildid, slotid) ON DELETE CASCADE ); -CREATE UNIQUE INDEX reaction_role_expiry_members ON reaction_role_expiring (guildid, userid, roleid); +CREATE INDEX schedule_session_members_users ON schedule_session_members(userid, slotid); + +-- }}} + +-- RoleMenus {{{ +CREATE TYPE RoleMenuType AS ENUM( + 'REACTION', + 'BUTTON', + 'DROPDOWN' +); + + +CREATE TABLE role_menus( + menuid SERIAL PRIMARY KEY, + guildid BIGINT NOT NULL REFERENCES guild_config (guildid) ON DELETE CASCADE, + channelid BIGINT, + messageid BIGINT, + name TEXT NOT NULL, + enabled BOOLEAN NOT NULL DEFAULT True, + required_roleid BIGINT, + sticky BOOLEAN, + refunds BOOLEAN, + obtainable INTEGER, + menutype RoleMenuType NOT NULL, + templateid INTEGER, + rawmessage TEXT, + default_price INTEGER, + event_log BOOLEAN +); +CREATE INDEX role_menu_guildid ON role_menus (guildid); + + + +CREATE TABLE role_menu_roles( + menuroleid SERIAL PRIMARY KEY, + menuid INTEGER NOT NULL REFERENCES role_menus (menuid) ON DELETE CASCADE, + roleid BIGINT NOT NULL, + label TEXT NOT NULL, + emoji TEXT, + description TEXT, + price INTEGER, + duration INTEGER, + rawreply TEXT +); +CREATE INDEX role_menu_roles_menuid ON role_menu_roles (menuid); +CREATE INDEX role_menu_roles_roleid ON role_menu_roles (roleid); + + +CREATE TABLE role_menu_history( + equipid SERIAL PRIMARY KEY, + menuid INTEGER NOT NULL REFERENCES role_menus (menuid) ON DELETE CASCADE, + roleid BIGINT NOT NULL, + userid BIGINT NOT NULL, + obtained_at TIMESTAMPTZ NOT NULL, + transactionid INTEGER REFERENCES coin_transactions (transactionid) ON DELETE SET NULL, + expires_at TIMESTAMPTZ, + removed_at TIMESTAMPTZ +); +CREATE INDEX role_menu_history_menuid ON role_menu_history (menuid); +CREATE INDEX role_menu_history_roleid ON role_menu_history (roleid); -- }}} -- Member Role Data {{{ @@ -845,12 +1136,40 @@ CREATE INDEX member_profile_tags_members ON member_profile_tags (guildid, userid -- }}} -- Member goals {{{ +CREATE TABLE user_weekly_goals( + userid BIGINT NOT NULL, + weekid INTEGER NOT NULL, + task_goal INTEGER, + study_goal INTEGER, + review_goal INTEGER, + message_goal INTEGER, + _timestamp TIMESTAMPTZ DEFAULT now(), + PRIMARY KEY (userid, weekid), + FOREIGN KEY (userid) REFERENCES user_config (userid) ON DELETE CASCADE +); +CREATE INDEX user_weekly_goals_users ON user_weekly_goals (userid); + +CREATE TABLE user_monthly_goals( + userid BIGINT NOT NULL, + monthid INTEGER NOT NULL, + task_goal INTEGER, + study_goal INTEGER, + review_goal INTEGER, + message_goal INTEGER, + _timestamp TIMESTAMPTZ DEFAULT now(), + PRIMARY KEY (userid, monthid), + FOREIGN KEY (userid) REFERENCES user_config (userid) ON DELETE CASCADE +); +CREATE INDEX user_monthly_goals_users ON user_monthly_goals (userid); + CREATE TABLE member_weekly_goals( guildid BIGINT NOT NULL, userid BIGINT NOT NULL, weekid INTEGER NOT NULL, -- Epoch time of the start of the UTC week study_goal INTEGER, task_goal INTEGER, + review_goal INTEGER, + message_goal INTEGER, _timestamp TIMESTAMPTZ DEFAULT now(), PRIMARY KEY (guildid, userid, weekid), FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) ON DELETE CASCADE @@ -875,6 +1194,8 @@ CREATE TABLE member_monthly_goals( monthid INTEGER NOT NULL, -- Epoch time of the start of the UTC month study_goal INTEGER, task_goal INTEGER, + review_goal INTEGER, + message_goal INTEGER, _timestamp TIMESTAMPTZ DEFAULT now(), PRIMARY KEY (guildid, userid, monthid), FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) ON DELETE CASCADE @@ -899,13 +1220,18 @@ CREATE INDEX member_monthly_goal_tasks_members_monthly ON member_monthly_goal_ta create TABLE timers( channelid BIGINT PRIMARY KEY, guildid BIGINT NOT NULL REFERENCES guild_config (guildid), - text_channelid BIGINT, + notification_channelid BIGINT, focus_length INTEGER NOT NULL, break_length INTEGER NOT NULL, - last_started TIMESTAMPTZ NOT NULL, + last_started TIMESTAMPTZ, inactivity_threshold INTEGER, channel_name TEXT, - pretty_name TEXT + pretty_name TEXT, + owenrid BIGINT REFERENCES user_config, + manager_roleid BIGINT, + last_messageid BIGINT, + voice_alerts BOOLEAN, + auto_restart BOOLEAN ); CREATE INDEX timers_guilds ON timers (guildid); -- }}} @@ -1038,4 +1364,69 @@ CREATE TABLE premium_guild_contributions( -- }}} +-- Analytics Data {{{ +CREATE SCHEMA "analytics"; + +CREATE TABLE analytics.snapshots( + snapshotid SERIAL PRIMARY KEY, + appname TEXT NOT NULL REFERENCES bot_config (appname), + guild_count INTEGER NOT NULL, + member_count INTEGER NOT NULL, + user_count INTEGER NOT NULL, + in_voice INTEGER NOT NULL, + created_at TIMESTAMPTZ NOT NULL DEFAULT (now() at time zone 'utc') +); + + +CREATE TABLE analytics.events( + eventid SERIAL PRIMARY KEY, + appname TEXT NOT NULL REFERENCES bot_config (appname), + ctxid BIGINT, + guildid BIGINT, + created_at TIMESTAMPTZ NOT NULL DEFAULT (now() at time zone 'utc') +); + +CREATE TYPE analytics.CommandStatus AS ENUM( + 'COMPLETED', + 'CANCELLED', + 'FAILED' +); + +CREATE TABLE analytics.commands( + cmdname TEXT NOT NULL, + cogname TEXT, + userid BIGINT NOT NULL, + status analytics.CommandStatus NOT NULL, + error TEXT, + execution_time REAL NOT NULL +) INHERITS (analytics.events); + + +CREATE TYPE analytics.GuildAction AS ENUM( + 'JOINED', + 'LEFT' +); + +CREATE TABLE analytics.guilds( + guildid BIGINT NOT NULL, + action analytics.GuildAction NOT NULL +) INHERITS (analytics.events); + + +CREATE TYPE analytics.VoiceAction AS ENUM( + 'JOINED', + 'LEFT' +); + +CREATE TABLE analytics.voice_sessions( + userid BIGINT NOT NULL, + action analytics.VoiceAction NOT NULL +) INHERITS (analytics.events); + +CREATE TABLE analytics.gui_renders( + cardname TEXT NOT NULL, + duration INTEGER NOT NULL +) INHERITS (analytics.events); +-- }}} + -- vim: set fdm=marker: