From ac71c4da9bd50ea6fe8eced4a28e62c16fe9a8ec Mon Sep 17 00:00:00 2001 From: Conatum Date: Mon, 29 Nov 2021 13:33:21 +0200 Subject: [PATCH] (sessions): Add `study_time_since` function. New `study_time_since` database function from session history. Add `Lion.timezone`. Add `Lion.day_start`. Add `Lion.studied_today`. Made `Table.queries` an instance variable. Renamed the session channel types. --- bot/core/data.py | 62 +++++++++++++++--------------- bot/core/lion.py | 35 +++++++++++++++++ bot/data/interfaces.py | 2 +- bot/modules/study/tracking/data.py | 27 +++++++++++++ data/migration/v5-v6/migration.sql | 62 ++++++++++++++++++++++++------ data/schema.sql | 40 ++++++++++++++++++- 6 files changed, 184 insertions(+), 44 deletions(-) diff --git a/bot/core/data.py b/bot/core/data.py index c33914d7..8ae74874 100644 --- a/bot/core/data.py +++ b/bot/core/data.py @@ -20,37 +20,6 @@ user_config = RowTable( ) -@user_config.save_query -def add_pending(pending): - """ - pending: - List of tuples of the form `(userid, pending_coins, pending_time)`. - """ - with lions.conn: - cursor = lions.conn.cursor() - data = execute_values( - cursor, - """ - UPDATE members - SET - coins = coins + t.coin_diff, - tracked_time = tracked_time + t.time_diff - FROM - (VALUES %s) - AS - t (guildid, userid, coin_diff, time_diff) - WHERE - members.guildid = t.guildid - AND - members.userid = t.userid - RETURNING * - """, - pending, - fetch=True - ) - return lions._make_rows(*data) - - guild_config = RowTable( 'guild_config', ('guildid', 'admin_role', 'mod_role', 'event_log_channel', 'alert_channel', @@ -84,6 +53,37 @@ lions = RowTable( lion_ranks = Table('member_ranks', attach_as='lion_ranks') +@lions.save_query +def add_pending(pending): + """ + pending: + List of tuples of the form `(userid, pending_coins, pending_time)`. + """ + with lions.conn: + cursor = lions.conn.cursor() + data = execute_values( + cursor, + """ + UPDATE members + SET + coins = coins + t.coin_diff, + tracked_time = tracked_time + t.time_diff + FROM + (VALUES %s) + AS + t (guildid, userid, coin_diff, time_diff) + WHERE + members.guildid = t.guildid + AND + members.userid = t.userid + RETURNING * + """, + pending, + fetch=True + ) + return lions._make_rows(*data) + + global_guild_blacklist = Table('global_guild_blacklist') global_user_blacklist = Table('global_user_blacklist') ignored_members = Table('ignored_members') diff --git a/bot/core/lion.py b/bot/core/lion.py index b9b10092..d9eb7ea1 100644 --- a/bot/core/lion.py +++ b/bot/core/lion.py @@ -1,4 +1,5 @@ import pytz +import datetime from meta import client from data import tables as tb @@ -41,6 +42,7 @@ class Lion: if key in cls._lions: return cls._lions[key] else: + # TODO: Debug log lion = tb.lions.fetch(key) if not lion: tb.lions.create_row( @@ -95,6 +97,39 @@ class Lion: """ return int(self.data.coins + self._pending_coins) + @property + def session(self): + """ + The current study session the user is in, if any. + """ + if 'sessions' not in client.objects: + raise ValueError("Cannot retrieve session before Study module is initialised!") + return client.objects['sessions'][self.guildid].get(self.userid, None) + + @property + def timezone(self): + """ + The user's configured timezone. + Shortcut to `Lion.settings.timezone.value`. + """ + return self.settings.timezone.value + + @property + def day_start(self): + """ + A timezone aware datetime representing the start of the user's day (in their configured timezone). + """ + now = datetime.datetime.now(tz=self.timezone) + return now.replace(hour=0, minute=0, second=0, microsecond=0) + + @property + def studied_today(self): + """ + The amount of time, in seconds, that the member has studied today. + Extracted from the session history. + """ + return tb.session_history.queries.study_time_since(self.guildid, self.userid, self.day_start) + def localize(self, naive_utc_dt): """ Localise the provided naive UTC datetime into the user's timezone. diff --git a/bot/data/interfaces.py b/bot/data/interfaces.py index 42810e72..7673b0e0 100644 --- a/bot/data/interfaces.py +++ b/bot/data/interfaces.py @@ -45,10 +45,10 @@ class Table: Intended to be subclassed to provide more derivative access for specific tables. """ conn = conn - queries = DotDict() def __init__(self, name, attach_as=None): self.name = name + self.queries = DotDict() tables[attach_as or name] = self @_connection_guard diff --git a/bot/modules/study/tracking/data.py b/bot/modules/study/tracking/data.py index deab3816..5940bf63 100644 --- a/bot/modules/study/tracking/data.py +++ b/bot/modules/study/tracking/data.py @@ -1,7 +1,21 @@ from data import Table, RowTable, tables +from utils.lib import FieldEnum + untracked_channels = Table('untracked_channels') + +class SessionChannelType(FieldEnum): + """ + The possible session channel types. + """ + # NOTE: "None" stands for Unknown, and the STANDARD description should be replaced with the channel name + STANDARD = 'STANDARD', "Standard" + ACCOUNTABILITY = 'ACCOUNTABILITY', "Accountability Room" + RENTED = 'RENTED', "Private Room" + EXTERNAL = 'EXTERNAL', "Unknown" + + session_history = Table('session_history') current_sessions = RowTable( 'current_sessions', @@ -30,3 +44,16 @@ def close_study_session(guildid, userid): current_sessions.row_cache.pop((guildid, userid), None) # Use the function output to update the member cache tables.lions._make_rows(*rows) + + +@session_history.save_query +def study_time_since(guildid, userid, timestamp): + """ + Retrieve the total member study time (in seconds) since the given timestamp. + Includes the current session, if it exists. + """ + with session_history.conn as conn: + cursor = conn.cursor() + cursor.callproc('study_time_since', (guildid, userid, timestamp)) + rows = cursor.fetchall() + return (rows[0][0] if rows else None) or 0 diff --git a/data/migration/v5-v6/migration.sql b/data/migration/v5-v6/migration.sql index 70ec3843..9e404e13 100644 --- a/data/migration/v5-v6/migration.sql +++ b/data/migration/v5-v6/migration.sql @@ -1,19 +1,22 @@ -/* 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 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; + +DROP FUNCTION IF EXISTS study_time_since; -/* 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 ( + 'STANDARD', 'ACCOUNTABILITY', 'RENTED', - 'EXTERNAL', - 'MIGRATED' + 'EXTERNAL' ); CREATE TABLE session_history( @@ -134,3 +137,40 @@ CREATE VIEW new_study_badges AS WHERE last_study_badgeid IS DISTINCT FROM current_study_badgeid ORDER BY guildid; + + +CREATE FUNCTION study_time_since(_guildid BIGINT, _userid BIGINT, _timestamp TIMESTAMPTZ) + RETURNS INTEGER +AS $$ + BEGIN + RETURN ( + SELECT + SUM( + CASE + WHEN start_time >= _timestamp THEN duration + ELSE EXTRACT(EPOCH FROM (end_time - _timestamp)) + END + ) + FROM ( + SELECT + start_time, + duration, + (start_time + duration * interval '1 second') AS end_time + FROM session_history + WHERE + 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=_guildid + AND userid=_userid + ) AS sessions + ); + END; +$$ LANGUAGE PLPGSQL; diff --git a/data/schema.sql b/data/schema.sql index aba91dee..51ba3ecd 100644 --- a/data/schema.sql +++ b/data/schema.sql @@ -412,12 +412,13 @@ update_timestamp_column(); -- Study Session Data {{{ CREATE TYPE SessionChannelType AS ENUM ( + 'STANDARD', 'ACCOUNTABILITY', 'RENTED', 'EXTERNAL', - 'MIGRATED' ); + CREATE TABLE session_history( sessionid SERIAL PRIMARY KEY, guildid BIGINT NOT NULL, @@ -453,6 +454,43 @@ CREATE TABLE current_sessions( CREATE UNIQUE INDEX current_session_members ON current_sessions (guildid, userid); +CREATE FUNCTION study_time_since(_guildid BIGINT, _userid BIGINT, _timestamp TIMESTAMPTZ) + RETURNS INTEGER +AS $$ + BEGIN + RETURN ( + SELECT + SUM( + CASE + WHEN start_time >= _timestamp THEN duration + ELSE EXTRACT(EPOCH FROM (end_time - _timestamp)) + END + ) + FROM ( + SELECT + start_time, + duration, + (start_time + duration * interval '1 second') AS end_time + FROM session_history + WHERE + 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=_guildid + AND userid=_userid + ) AS sessions + ); + END; +$$ LANGUAGE PLPGSQL; + + CREATE FUNCTION close_study_session(_guildid BIGINT, _userid BIGINT) RETURNS SETOF members AS $$