(sessions): Add customisable study tags.
This commit is contained in:
@@ -15,4 +15,53 @@ create TABLE timers(
|
||||
CREATE INDEX timers_guilds ON timers (guildid);
|
||||
-- }}}
|
||||
|
||||
-- Session tags {{{
|
||||
ALTER TABLE current_sessions
|
||||
ADD COLUMN rating INTEGER,
|
||||
ADD COLUMN tag TEXT;
|
||||
|
||||
ALTER TABLE session_history
|
||||
ADD COLUMN rating INTEGER,
|
||||
ADD COLUMN tag TEXT;
|
||||
|
||||
DROP FUNCTION close_study_session;
|
||||
|
||||
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, 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,
|
||||
(total_duration * hourly_coins + live_duration * hourly_live_coins) / 3600
|
||||
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;
|
||||
-- }}}
|
||||
|
||||
INSERT INTO VersionHistory (version, author) VALUES (8, 'v7-v8 migration');
|
||||
|
||||
@@ -427,6 +427,8 @@ CREATE TABLE session_history(
|
||||
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,
|
||||
@@ -442,6 +444,8 @@ CREATE TABLE current_sessions(
|
||||
userid BIGINT NOT NULL,
|
||||
channelid BIGINT,
|
||||
channel_type SessionChannelType,
|
||||
rating INTEGER,
|
||||
tag TEXT,
|
||||
start_time TIMESTAMPTZ DEFAULT now(),
|
||||
live_duration INTEGER DEFAULT 0,
|
||||
live_start TIMESTAMPTZ,
|
||||
@@ -510,11 +514,11 @@ AS $$
|
||||
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,
|
||||
guildid, userid, channelid, rating, tag, channel_type, start_time,
|
||||
duration, stream_duration, video_duration, live_duration,
|
||||
coins_earned
|
||||
) SELECT
|
||||
guildid, userid, channelid, channel_type, start_time,
|
||||
guildid, userid, channelid, rating, tag, channel_type, start_time,
|
||||
total_duration, total_stream_duration, total_video_duration, total_live_duration,
|
||||
(total_duration * hourly_coins + live_duration * hourly_live_coins) / 3600
|
||||
FROM current_sesh
|
||||
|
||||
Reference in New Issue
Block a user