(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.
This commit is contained in:
@@ -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 = RowTable(
|
||||||
'guild_config',
|
'guild_config',
|
||||||
('guildid', 'admin_role', 'mod_role', 'event_log_channel', 'alert_channel',
|
('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')
|
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_guild_blacklist = Table('global_guild_blacklist')
|
||||||
global_user_blacklist = Table('global_user_blacklist')
|
global_user_blacklist = Table('global_user_blacklist')
|
||||||
ignored_members = Table('ignored_members')
|
ignored_members = Table('ignored_members')
|
||||||
|
|||||||
@@ -1,4 +1,5 @@
|
|||||||
import pytz
|
import pytz
|
||||||
|
import datetime
|
||||||
|
|
||||||
from meta import client
|
from meta import client
|
||||||
from data import tables as tb
|
from data import tables as tb
|
||||||
@@ -41,6 +42,7 @@ class Lion:
|
|||||||
if key in cls._lions:
|
if key in cls._lions:
|
||||||
return cls._lions[key]
|
return cls._lions[key]
|
||||||
else:
|
else:
|
||||||
|
# TODO: Debug log
|
||||||
lion = tb.lions.fetch(key)
|
lion = tb.lions.fetch(key)
|
||||||
if not lion:
|
if not lion:
|
||||||
tb.lions.create_row(
|
tb.lions.create_row(
|
||||||
@@ -95,6 +97,39 @@ class Lion:
|
|||||||
"""
|
"""
|
||||||
return int(self.data.coins + self._pending_coins)
|
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):
|
def localize(self, naive_utc_dt):
|
||||||
"""
|
"""
|
||||||
Localise the provided naive UTC datetime into the user's timezone.
|
Localise the provided naive UTC datetime into the user's timezone.
|
||||||
|
|||||||
@@ -45,10 +45,10 @@ class Table:
|
|||||||
Intended to be subclassed to provide more derivative access for specific tables.
|
Intended to be subclassed to provide more derivative access for specific tables.
|
||||||
"""
|
"""
|
||||||
conn = conn
|
conn = conn
|
||||||
queries = DotDict()
|
|
||||||
|
|
||||||
def __init__(self, name, attach_as=None):
|
def __init__(self, name, attach_as=None):
|
||||||
self.name = name
|
self.name = name
|
||||||
|
self.queries = DotDict()
|
||||||
tables[attach_as or name] = self
|
tables[attach_as or name] = self
|
||||||
|
|
||||||
@_connection_guard
|
@_connection_guard
|
||||||
|
|||||||
@@ -1,7 +1,21 @@
|
|||||||
from data import Table, RowTable, tables
|
from data import Table, RowTable, tables
|
||||||
|
from utils.lib import FieldEnum
|
||||||
|
|
||||||
|
|
||||||
untracked_channels = Table('untracked_channels')
|
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')
|
session_history = Table('session_history')
|
||||||
current_sessions = RowTable(
|
current_sessions = RowTable(
|
||||||
'current_sessions',
|
'current_sessions',
|
||||||
@@ -30,3 +44,16 @@ def close_study_session(guildid, userid):
|
|||||||
current_sessions.row_cache.pop((guildid, userid), None)
|
current_sessions.row_cache.pop((guildid, userid), None)
|
||||||
# Use the function output to update the member cache
|
# Use the function output to update the member cache
|
||||||
tables.lions._make_rows(*rows)
|
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
|
||||||
|
|||||||
@@ -1,19 +1,22 @@
|
|||||||
/* DROP TYPE IF EXISTS SessionChannelType CASCADE; */
|
DROP TYPE IF EXISTS SessionChannelType CASCADE;
|
||||||
/* DROP TABLE IF EXISTS session_history CASCADE; */
|
DROP TABLE IF EXISTS session_history CASCADE;
|
||||||
/* DROP TABLE IF EXISTS current_sessions CASCADE; */
|
DROP TABLE IF EXISTS current_sessions CASCADE;
|
||||||
/* DROP FUNCTION IF EXISTS close_study_session; */
|
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 (
|
CREATE TYPE SessionChannelType AS ENUM (
|
||||||
|
'STANDARD',
|
||||||
'ACCOUNTABILITY',
|
'ACCOUNTABILITY',
|
||||||
'RENTED',
|
'RENTED',
|
||||||
'EXTERNAL',
|
'EXTERNAL'
|
||||||
'MIGRATED'
|
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE TABLE session_history(
|
CREATE TABLE session_history(
|
||||||
@@ -134,3 +137,40 @@ CREATE VIEW new_study_badges AS
|
|||||||
WHERE
|
WHERE
|
||||||
last_study_badgeid IS DISTINCT FROM current_study_badgeid
|
last_study_badgeid IS DISTINCT FROM current_study_badgeid
|
||||||
ORDER BY guildid;
|
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;
|
||||||
|
|||||||
@@ -412,12 +412,13 @@ update_timestamp_column();
|
|||||||
|
|
||||||
-- Study Session Data {{{
|
-- Study Session Data {{{
|
||||||
CREATE TYPE SessionChannelType AS ENUM (
|
CREATE TYPE SessionChannelType AS ENUM (
|
||||||
|
'STANDARD',
|
||||||
'ACCOUNTABILITY',
|
'ACCOUNTABILITY',
|
||||||
'RENTED',
|
'RENTED',
|
||||||
'EXTERNAL',
|
'EXTERNAL',
|
||||||
'MIGRATED'
|
|
||||||
);
|
);
|
||||||
|
|
||||||
|
|
||||||
CREATE TABLE session_history(
|
CREATE TABLE session_history(
|
||||||
sessionid SERIAL PRIMARY KEY,
|
sessionid SERIAL PRIMARY KEY,
|
||||||
guildid BIGINT NOT NULL,
|
guildid BIGINT NOT NULL,
|
||||||
@@ -453,6 +454,43 @@ CREATE TABLE current_sessions(
|
|||||||
CREATE UNIQUE INDEX current_session_members ON current_sessions (guildid, userid);
|
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)
|
CREATE FUNCTION close_study_session(_guildid BIGINT, _userid BIGINT)
|
||||||
RETURNS SETOF members
|
RETURNS SETOF members
|
||||||
AS $$
|
AS $$
|
||||||
|
|||||||
Reference in New Issue
Block a user