[DB][CORE][Topgg] Update DB to accommodate Topgg module
This commit is contained in:
@@ -14,7 +14,7 @@ meta = RowTable(
|
|||||||
|
|
||||||
user_config = RowTable(
|
user_config = RowTable(
|
||||||
'user_config',
|
'user_config',
|
||||||
('userid', 'timezone'),
|
('userid', 'timezone', 'remaind_upvote'),
|
||||||
'userid',
|
'userid',
|
||||||
cache=TTLCache(5000, ttl=60*5)
|
cache=TTLCache(5000, ttl=60*5)
|
||||||
)
|
)
|
||||||
|
|||||||
@@ -1,4 +1,4 @@
|
|||||||
from data import RowTable
|
from data.interfaces import RowTable
|
||||||
|
|
||||||
|
|
||||||
reminders = RowTable(
|
reminders = RowTable(
|
||||||
|
|||||||
@@ -1,4 +1,4 @@
|
|||||||
from data.interfaces import RowTable, Table
|
from data.interfaces import RowTable
|
||||||
|
|
||||||
topggvotes = RowTable(
|
topggvotes = RowTable(
|
||||||
'topgg',
|
'topgg',
|
||||||
|
|||||||
72
data/migration/v8-v9/migration.sql
Normal file
72
data/migration/v8-v9/migration.sql
Normal file
@@ -0,0 +1,72 @@
|
|||||||
|
ALTER TABLE user_config
|
||||||
|
ADD COLUMN remaind_upvote BOOLEAN DEFAULT TRUE
|
||||||
|
|
||||||
|
-- Topgg Data {{{
|
||||||
|
CREATE TABLE IF NOT EXISTS topgg(
|
||||||
|
voteid SERIAL PRIMARY KEY,
|
||||||
|
userid BIGINT NOT NULL,
|
||||||
|
boostedTimestamp TIMESTAMPTZ NOT NULL
|
||||||
|
);
|
||||||
|
CREATE INDEX topgg_member ON topgg (guildid, userid);
|
||||||
|
-- }}}
|
||||||
|
|
||||||
|
DROP FUNCTION close_study_session(_guildid BIGINT, _userid BIGINT);
|
||||||
|
|
||||||
|
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
|
||||||
|
), bonus_userid AS (
|
||||||
|
SELECT COUNT(boostedTimestamp),
|
||||||
|
CASE WHEN EXISTS (
|
||||||
|
SELECT 1 FROM Topgg
|
||||||
|
WHERE Topgg.userid=_userid AND EXTRACT(EPOCH FROM (NOW() - boostedTimestamp)) < 12.5*60*60
|
||||||
|
) THEN
|
||||||
|
(array_agg(
|
||||||
|
CASE WHEN boostedTimestamp <= current_sesh.start_time THEN
|
||||||
|
1.25
|
||||||
|
ELSE
|
||||||
|
(((current_sesh.total_duration - EXTRACT(EPOCH FROM (boostedTimestamp - current_sesh.start_time)))/current_sesh.total_duration)*0.25)+1
|
||||||
|
END))[1]
|
||||||
|
ELSE
|
||||||
|
1
|
||||||
|
END
|
||||||
|
AS bonus
|
||||||
|
FROM Topgg, current_sesh
|
||||||
|
WHERE Topgg.userid=_userid AND EXTRACT(EPOCH FROM (NOW() - boostedTimestamp)) < 12.5*60*60
|
||||||
|
ORDER BY (array_agg(boostedTimestamp))[1] DESC LIMIT 1
|
||||||
|
), 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) * bonus_userid.bonus )/ 3600
|
||||||
|
FROM current_sesh, bonus_userid
|
||||||
|
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, 'v8-v9 migration');
|
||||||
@@ -41,7 +41,8 @@ CREATE TABLE global_guild_blacklist(
|
|||||||
-- User configuration data {{{
|
-- User configuration data {{{
|
||||||
CREATE TABLE user_config(
|
CREATE TABLE user_config(
|
||||||
userid BIGINT PRIMARY KEY,
|
userid BIGINT PRIMARY KEY,
|
||||||
timezone TEXT
|
timezone TEXT,
|
||||||
|
remaind_upvote BOOLEAN DEFAULT TRUE
|
||||||
);
|
);
|
||||||
-- }}}
|
-- }}}
|
||||||
|
|
||||||
@@ -144,15 +145,6 @@ CREATE TABLE tasklist(
|
|||||||
);
|
);
|
||||||
CREATE INDEX tasklist_users ON tasklist (userid);
|
CREATE INDEX tasklist_users ON tasklist (userid);
|
||||||
|
|
||||||
-- Topgg Data {{{
|
|
||||||
create TABLE topgg(
|
|
||||||
voteid SERIAL PRIMARY KEY,
|
|
||||||
userid BIGINT NOT NULL,
|
|
||||||
boostedTimestamp TIMESTAMPTZ NOT NULL
|
|
||||||
);
|
|
||||||
CREATE INDEX topgg_member ON topgg (guildid, userid);
|
|
||||||
-- }}}
|
|
||||||
|
|
||||||
CREATE TABLE tasklist_channels(
|
CREATE TABLE tasklist_channels(
|
||||||
guildid BIGINT NOT NULL,
|
guildid BIGINT NOT NULL,
|
||||||
channelid BIGINT NOT NULL
|
channelid BIGINT NOT NULL
|
||||||
@@ -521,6 +513,25 @@ AS $$
|
|||||||
stream_duration + COALESCE(EXTRACT(EPOCH FROM (NOW() - stream_start)), 0) AS total_stream_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,
|
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
|
live_duration + COALESCE(EXTRACT(EPOCH FROM (NOW() - live_start)), 0) AS total_live_duration
|
||||||
|
), bonus_userid AS (
|
||||||
|
SELECT COUNT(boostedTimestamp),
|
||||||
|
CASE WHEN EXISTS (
|
||||||
|
SELECT 1 FROM Topgg
|
||||||
|
WHERE Topgg.userid=_userid AND EXTRACT(EPOCH FROM (NOW() - boostedTimestamp)) < 12.5*60*60
|
||||||
|
) THEN
|
||||||
|
(array_agg(
|
||||||
|
CASE WHEN boostedTimestamp <= current_sesh.start_time THEN
|
||||||
|
1.25
|
||||||
|
ELSE
|
||||||
|
(((current_sesh.total_duration - EXTRACT(EPOCH FROM (boostedTimestamp - current_sesh.start_time)))/current_sesh.total_duration)*0.25)+1
|
||||||
|
END))[1]
|
||||||
|
ELSE
|
||||||
|
1
|
||||||
|
END
|
||||||
|
AS bonus
|
||||||
|
FROM Topgg, current_sesh
|
||||||
|
WHERE Topgg.userid=_userid AND EXTRACT(EPOCH FROM (NOW() - boostedTimestamp)) < 12.5*60*60
|
||||||
|
ORDER BY (array_agg(boostedTimestamp))[1] DESC LIMIT 1
|
||||||
), saved_sesh AS (
|
), saved_sesh AS (
|
||||||
INSERT INTO session_history (
|
INSERT INTO session_history (
|
||||||
guildid, userid, channelid, rating, tag, channel_type, start_time,
|
guildid, userid, channelid, rating, tag, channel_type, start_time,
|
||||||
@@ -529,8 +540,8 @@ AS $$
|
|||||||
) SELECT
|
) SELECT
|
||||||
guildid, userid, channelid, rating, tag, 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, total_stream_duration, total_video_duration, total_live_duration,
|
||||||
(total_duration * hourly_coins + live_duration * hourly_live_coins) / 3600
|
((total_duration * hourly_coins + live_duration * hourly_live_coins) * bonus_userid.bonus )/ 3600
|
||||||
FROM current_sesh
|
FROM current_sesh, bonus_userid
|
||||||
RETURNING *
|
RETURNING *
|
||||||
)
|
)
|
||||||
UPDATE members
|
UPDATE members
|
||||||
@@ -775,4 +786,13 @@ create TABLE timers(
|
|||||||
CREATE INDEX timers_guilds ON timers (guildid);
|
CREATE INDEX timers_guilds ON timers (guildid);
|
||||||
-- }}}
|
-- }}}
|
||||||
|
|
||||||
|
-- Topgg Data {{{
|
||||||
|
create TABLE topgg(
|
||||||
|
voteid SERIAL PRIMARY KEY,
|
||||||
|
userid BIGINT NOT NULL,
|
||||||
|
boostedTimestamp TIMESTAMPTZ NOT NULL
|
||||||
|
);
|
||||||
|
CREATE INDEX topgg_member ON topgg (guildid, userid);
|
||||||
|
-- }}}
|
||||||
|
|
||||||
-- vim: set fdm=marker:
|
-- vim: set fdm=marker:
|
||||||
|
|||||||
Reference in New Issue
Block a user