(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:
@@ -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;
|
||||
|
||||
@@ -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 $$
|
||||
|
||||
Reference in New Issue
Block a user