feature (sessions): Core session tracker.

Base `Session` system with event trackers.
This commit is contained in:
2021-10-31 20:15:32 +02:00
parent 5ea7d06dae
commit 65fcfe0289
6 changed files with 440 additions and 9 deletions

View File

@@ -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: