From 65fcfe0289f5cbb88c508613eefa6531dc62d531 Mon Sep 17 00:00:00 2001 From: Conatum Date: Sun, 31 Oct 2021 20:15:32 +0200 Subject: [PATCH] feature (sessions): Core session tracker. Base `Session` system with event trackers. --- bot/modules/study/tracking/__init__.py | 1 - bot/modules/study/tracking/data.py | 31 +++- bot/modules/study/tracking/session_tracker.py | 150 ++++++++++++++++++ bot/modules/study/tracking/settings.py | 11 ++ data/migration/v5-v6/migration.sql | 136 ++++++++++++++++ data/schema.sql | 120 +++++++++++++- 6 files changed, 440 insertions(+), 9 deletions(-) create mode 100644 data/migration/v5-v6/migration.sql diff --git a/bot/modules/study/tracking/__init__.py b/bot/modules/study/tracking/__init__.py index a80dd7a7..ba8de231 100644 --- a/bot/modules/study/tracking/__init__.py +++ b/bot/modules/study/tracking/__init__.py @@ -1,4 +1,3 @@ from . import data from . import settings -from . import time_tracker from . import session_tracker diff --git a/bot/modules/study/tracking/data.py b/bot/modules/study/tracking/data.py index 12bd8d77..deab3816 100644 --- a/bot/modules/study/tracking/data.py +++ b/bot/modules/study/tracking/data.py @@ -1,3 +1,32 @@ -from data import Table +from data import Table, RowTable, tables untracked_channels = Table('untracked_channels') + +session_history = Table('session_history') +current_sessions = RowTable( + 'current_sessions', + ('guildid', 'userid', 'channelid', 'channel_type', + 'start_time', + 'live_duration', 'live_start', + 'stream_duration', 'stream_start', + 'video_duration', 'video_start', + 'hourly_coins', 'hourly_live_coins'), + ('guildid', 'userid'), + cache={} # Keep all current sessions in cache +) + + +@current_sessions.save_query +def close_study_session(guildid, userid): + """ + Close a member's current session if it exists and update the member cache. + """ + # Execute the `close_study_session` database function + with current_sessions.conn as conn: + cursor = conn.cursor() + cursor.callproc('close_study_session', (guildid, userid)) + rows = cursor.fetchall() + # The row has been deleted, remove the from current sessions cache + current_sessions.row_cache.pop((guildid, userid), None) + # Use the function output to update the member cache + tables.lions._make_rows(*rows) diff --git a/bot/modules/study/tracking/session_tracker.py b/bot/modules/study/tracking/session_tracker.py index e69de29b..e44a2bc5 100644 --- a/bot/modules/study/tracking/session_tracker.py +++ b/bot/modules/study/tracking/session_tracker.py @@ -0,0 +1,150 @@ +import asyncio +import discord +from collections import defaultdict + +from utils.lib import utc_now +from ..module import module +from .data import current_sessions +from .settings import untracked_channels, hourly_reward, hourly_live_bonus, max_daily_study + + +class Session: + # TODO: Slots + sessions = defaultdict(dict) + + def __init__(self, guildid, userid): + self.guildid = guildid + self.userid = userid + self.key = (guildid, userid) + + @classmethod + def get(cls, guildid, userid): + """ + Fetch the current session for the provided member. + If there is no current session, returns `None`. + """ + return cls.sessions[guildid].get(userid, None) + + @classmethod + def start(cls, member: discord.Member, state: discord.VoiceState): + """ + Start a new study session for the provided member. + """ + guildid = member.guild.id + userid = member.id + now = utc_now() + + if userid in cls.sessions[guildid]: + raise ValueError("A session for this member already exists!") + # TODO: Handle daily study cap + # TODO: Calculate channel type + # TODO: Ensure lion + current_sessions.create_row( + guildid=guildid, + userid=userid, + channelid=state.channel.id, + channel_type=None, + start_time=now, + live_start=now if (state.self_video or state.self_stream) else None, + stream_start=now if state.self_stream else None, + video_start=now if state.self_video else None, + hourly_coins=hourly_reward.get(guildid).value, + hourly_live_coins=hourly_live_bonus.get(guildid).value + ) + session = cls(guildid, userid) + cls.sessions[guildid][userid] = session + return session + + @property + def data(self): + return current_sessions.fetch(self.key) + + def finish(self): + """ + Close the study session. + """ + self.sessions[self.guildid].pop(self.userid, None) + # Note that save_live_status doesn't need to be called here + # The database saving procedure will account for the values. + current_sessions.queries.close_study_session(*self.key) + + def save_live_status(self, state: discord.VoiceState): + """ + Update the saved live status of the member. + """ + has_video = state.self_video + has_stream = state.self_stream + is_live = has_video or has_stream + + now = utc_now() + data = self.data + + with data.batch_update(): + # Update video session stats + if data.video_start: + data.video_duration += (now - data.video_start).total_seconds() + data.video_start = now if has_video else None + + # Update stream session stats + if data.stream_start: + data.stream_duration += (now - data.stream_start).total_seconds() + data.stream_start = now if has_stream else None + + # Update overall live session stats + if data.live_start: + data.live_duration += (now - data.live_start).total_seconds() + data.live_start = now if is_live else None + + +async def session_voice_tracker(client, member, before, after): + """ + Voice update event dispatcher for study session tracking. + """ + guild = member.guild + session = Session.get(guild.id, member.id) + + if before.channel == after.channel: + # Voice state change without moving channel + if session and ((before.self_video != after.self_video) or (before.self_stream != after.self_stream)): + # Live status has changed! + session.save_live_status(after) + else: + # Member changed channel + # End the current session and start a new one, if applicable + # TODO: Max daily study session tasks + if session: + # End the current session + session.finish() + if after.channel: + blacklist = client.objects['blacklisted_users'] + guild_blacklist = client.objects['ignored_members'][guild.id] + untracked = untracked_channels.get(guild.id).data + start_session = ( + (after.channel.id not in untracked) + and (member.id not in blacklist) + and (member.id not in guild_blacklist) + ) + if start_session: + # Start a new session for the member + Session.start(member, after) + + +async def _init_session_tracker(client): + """ + Load ongoing saved study sessions into the session cache, + update them depending on the current voice states, + and attach the voice event handler. + """ + await client.wait_until_ready() + await untracked_channels.launch_task(client) + client.add_after_event("voice_state_update", session_voice_tracker) + + +@module.launch_task +async def launch_session_tracker(client): + """ + Launch the study session initialiser. + Doesn't block on the client being ready. + """ + client.objects['sessions'] = Session.sessions + asyncio.create_task(_init_session_tracker(client)) diff --git a/bot/modules/study/tracking/settings.py b/bot/modules/study/tracking/settings.py index 5861ab95..dc93cc00 100644 --- a/bot/modules/study/tracking/settings.py +++ b/bot/modules/study/tracking/settings.py @@ -111,3 +111,14 @@ class hourly_live_bonus(settings.Integer, settings.GuildSetting): @property def success_response(self): return "Members will be rewarded an extra `{}` LionCoins per hour if they stream.".format(self.formatted) + + +@GuildSettings.attach_setting +class max_daily_study(settings.Duration, settings.GuildSetting): + category = "Study Tracking" + + attr_name = "max_daily_study" + _data_column = "max_daily_study" + + display_name = "max_daily_study" + desc = "Maximum amount of study time ..." diff --git a/data/migration/v5-v6/migration.sql b/data/migration/v5-v6/migration.sql new file mode 100644 index 00000000..70ec3843 --- /dev/null +++ b/data/migration/v5-v6/migration.sql @@ -0,0 +1,136 @@ +/* DROP TYPE IF EXISTS SessionChannelType CASCADE; */ +/* DROP TABLE IF EXISTS session_history CASCADE; */ +/* DROP TABLE IF EXISTS current_sessions CASCADE; */ +/* DROP FUNCTION IF EXISTS close_study_session; */ + +/* DROP VIEW IF EXISTS current_sessions_totals CASCADE; */ +/* DROP VIEW IF EXISTS member_totals CASCADE; */ +/* DROP VIEW IF EXISTS member_ranks CASCADE; */ +/* DROP VIEW IF EXISTS current_study_badges CASCADE; */ +/* DROP VIEW IF EXISTS new_study_badges CASCADE; */ + +CREATE TYPE SessionChannelType AS ENUM ( + 'ACCOUNTABILITY', + 'RENTED', + 'EXTERNAL', + 'MIGRATED' +); + +CREATE TABLE session_history( + sessionid SERIAL PRIMARY KEY, + guildid BIGINT NOT NULL, + userid BIGINT NOT NULL, + channelid BIGINT, + channel_type SessionChannelType, + 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, + FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) ON DELETE CASCADE +); +CREATE INDEX session_history_members ON session_history (guildid, userid, start_time); + +CREATE TABLE current_sessions( + guildid BIGINT NOT NULL, + userid BIGINT NOT NULL, + channelid BIGINT, + channel_type SessionChannelType, + 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, + FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) ON DELETE CASCADE +); +CREATE UNIQUE INDEX current_session_members ON current_sessions (guildid, userid); + + +CREATE FUNCTION close_study_session(_guildid BIGINT, _userid BIGINT) + RETURNS SETOF members +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 + ), saved_sesh AS ( + INSERT INTO session_history ( + guildid, userid, channelid, channel_type, start_time, + duration, stream_duration, video_duration, live_duration, + coins_earned + ) SELECT + guildid, userid, channelid, channel_type, start_time, + total_duration, total_stream_duration, total_video_duration, total_live_duration, + (total_duration * hourly_coins + live_duration * hourly_live_coins) / 60 + FROM current_sesh + RETURNING * + ) + UPDATE members + SET + tracked_time=(tracked_time + saved_sesh.duration), + coins=(coins + saved_sesh.coins_earned) + FROM saved_sesh + WHERE members.guildid=saved_sesh.guildid AND members.userid=saved_sesh.userid + RETURNING members.*; + 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) / 60, 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; + +CREATE VIEW current_study_badges AS + SELECT + *, + (SELECT r.badgeid + FROM study_badges r + WHERE r.guildid = members_totals.guildid AND members_totals.tracked_time > r.required_time + ORDER BY r.required_time DESC + LIMIT 1) AS current_study_badgeid + FROM members_totals; + +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; diff --git a/data/schema.sql b/data/schema.sql index fe0158be..aba91dee 100644 --- a/data/schema.sql +++ b/data/schema.sql @@ -77,7 +77,8 @@ CREATE TABLE guild_config( greeting_message TEXT, returning_message TEXT, starting_funds INTEGER, - persist_roles BOOLEAN + persist_roles BOOLEAN, + max_daily_study INTEGER ); CREATE TABLE ignored_members( @@ -407,24 +408,127 @@ CREATE INDEX member_timestamps ON members (_timestamp); CREATE TRIGGER update_members_timstamp BEFORE UPDATE ON members FOR EACH ROW EXECUTE PROCEDURE update_timestamp_column(); +-- }}} + +-- Study Session Data {{{ +CREATE TYPE SessionChannelType AS ENUM ( + 'ACCOUNTABILITY', + 'RENTED', + 'EXTERNAL', + 'MIGRATED' +); + +CREATE TABLE session_history( + sessionid SERIAL PRIMARY KEY, + guildid BIGINT NOT NULL, + userid BIGINT NOT NULL, + channelid BIGINT, + channel_type SessionChannelType, + 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, + FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) ON DELETE CASCADE +); +CREATE INDEX session_history_members ON session_history (guildid, userid, start_time); + +CREATE TABLE current_sessions( + guildid BIGINT NOT NULL, + userid BIGINT NOT NULL, + channelid BIGINT, + channel_type SessionChannelType, + 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, + FOREIGN KEY (guildid, userid) REFERENCES members (guildid, userid) ON DELETE CASCADE +); +CREATE UNIQUE INDEX current_session_members ON current_sessions (guildid, userid); + + +CREATE FUNCTION close_study_session(_guildid BIGINT, _userid BIGINT) + RETURNS SETOF members +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 + ), saved_sesh AS ( + INSERT INTO session_history ( + guildid, userid, channelid, channel_type, start_time, + duration, stream_duration, video_duration, live_duration, + coins_earned + ) SELECT + guildid, userid, channelid, channel_type, start_time, + total_duration, total_stream_duration, total_video_duration, total_live_duration, + (total_duration * hourly_coins + live_duration * hourly_live_coins) / 60 + FROM current_sesh + RETURNING * + ) + UPDATE members + SET + tracked_time=(tracked_time + saved_sesh.duration), + coins=(coins + saved_sesh.coins_earned) + FROM saved_sesh + WHERE members.guildid=saved_sesh.guildid AND members.userid=saved_sesh.userid + RETURNING members.*; + 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) / 60, 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 tracked_time DESC, userid ASC) AS time_rank, - row_number() OVER (PARTITION BY guildid ORDER BY coins DESC, userid ASC) AS coin_rank - FROM members; - + 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.guildid AND members.tracked_time > r.required_time + WHERE r.guildid = members_totals.guildid AND members_totals.tracked_time > r.required_time ORDER BY r.required_time DESC LIMIT 1) AS current_study_badgeid - FROM members; + FROM members_totals; CREATE VIEW new_study_badges AS SELECT @@ -527,6 +631,7 @@ CREATE TABLE reaction_role_expiring( reactionid INTEGER REFERENCES reaction_role_reactions (reactionid) ON DELETE SET NULL ); CREATE UNIQUE INDEX reaction_role_expiry_members ON reaction_role_expiring (guildid, userid, roleid); +-- }}} -- Member Role Data {{{ CREATE TABLE past_member_roles( @@ -538,4 +643,5 @@ CREATE TABLE past_member_roles( ); CREATE INDEX member_role_persistence_members ON past_member_roles (guildid, userid); -- }}} + -- vim: set fdm=marker: