mirror of
https://github.com/LemmyNet/lemmy.git
synced 2024-11-23 23:11:11 +00:00
Add voters to active users (#4235)
* Add voters to active users * Edit formatting * Edit formatting * Edit formatting in down.sql * Fix person table inner joins * Remove post read from calculations
This commit is contained in:
parent
2d4037ba61
commit
60849355db
72
migrations/2023-12-06-180359_edit_active_users/down.sql
Normal file
72
migrations/2023-12-06-180359_edit_active_users/down.sql
Normal file
|
@ -0,0 +1,72 @@
|
||||||
|
CREATE OR REPLACE FUNCTION community_aggregates_activity (i text)
|
||||||
|
RETURNS TABLE (
|
||||||
|
count_ bigint,
|
||||||
|
community_id_ integer)
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
AS $$
|
||||||
|
BEGIN
|
||||||
|
RETURN query
|
||||||
|
SELECT
|
||||||
|
count(*),
|
||||||
|
community_id
|
||||||
|
FROM (
|
||||||
|
SELECT
|
||||||
|
c.creator_id,
|
||||||
|
p.community_id
|
||||||
|
FROM
|
||||||
|
comment c
|
||||||
|
INNER JOIN post p ON c.post_id = p.id
|
||||||
|
INNER JOIN person pe ON c.creator_id = pe.id
|
||||||
|
WHERE
|
||||||
|
c.published > ('now'::timestamp - i::interval)
|
||||||
|
AND pe.bot_account = FALSE
|
||||||
|
UNION
|
||||||
|
SELECT
|
||||||
|
p.creator_id,
|
||||||
|
p.community_id
|
||||||
|
FROM
|
||||||
|
post p
|
||||||
|
INNER JOIN person pe ON p.creator_id = pe.id
|
||||||
|
WHERE
|
||||||
|
p.published > ('now'::timestamp - i::interval)
|
||||||
|
AND pe.bot_account = FALSE) a
|
||||||
|
GROUP BY
|
||||||
|
community_id;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION site_aggregates_activity (i text)
|
||||||
|
RETURNS integer
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
count_ integer;
|
||||||
|
BEGIN
|
||||||
|
SELECT
|
||||||
|
count(*) INTO count_
|
||||||
|
FROM (
|
||||||
|
SELECT
|
||||||
|
c.creator_id
|
||||||
|
FROM
|
||||||
|
comment c
|
||||||
|
INNER JOIN person u ON c.creator_id = u.id
|
||||||
|
INNER JOIN person pe ON c.creator_id = pe.id
|
||||||
|
WHERE
|
||||||
|
c.published > ('now'::timestamp - i::interval)
|
||||||
|
AND u.local = TRUE
|
||||||
|
AND pe.bot_account = FALSE
|
||||||
|
UNION
|
||||||
|
SELECT
|
||||||
|
p.creator_id
|
||||||
|
FROM
|
||||||
|
post p
|
||||||
|
INNER JOIN person u ON p.creator_id = u.id
|
||||||
|
INNER JOIN person pe ON p.creator_id = pe.id
|
||||||
|
WHERE
|
||||||
|
p.published > ('now'::timestamp - i::interval)
|
||||||
|
AND u.local = TRUE
|
||||||
|
AND pe.bot_account = FALSE) a;
|
||||||
|
RETURN count_;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
114
migrations/2023-12-06-180359_edit_active_users/up.sql
Normal file
114
migrations/2023-12-06-180359_edit_active_users/up.sql
Normal file
|
@ -0,0 +1,114 @@
|
||||||
|
-- Edit community aggregates to include voters as active users
|
||||||
|
CREATE OR REPLACE FUNCTION community_aggregates_activity (i text)
|
||||||
|
RETURNS TABLE (
|
||||||
|
count_ bigint,
|
||||||
|
community_id_ integer)
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
AS $$
|
||||||
|
BEGIN
|
||||||
|
RETURN query
|
||||||
|
SELECT
|
||||||
|
count(*),
|
||||||
|
community_id
|
||||||
|
FROM (
|
||||||
|
SELECT
|
||||||
|
c.creator_id,
|
||||||
|
p.community_id
|
||||||
|
FROM
|
||||||
|
comment c
|
||||||
|
INNER JOIN post p ON c.post_id = p.id
|
||||||
|
INNER JOIN person pe ON c.creator_id = pe.id
|
||||||
|
WHERE
|
||||||
|
c.published > ('now'::timestamp - i::interval)
|
||||||
|
AND pe.bot_account = FALSE
|
||||||
|
UNION
|
||||||
|
SELECT
|
||||||
|
p.creator_id,
|
||||||
|
p.community_id
|
||||||
|
FROM
|
||||||
|
post p
|
||||||
|
INNER JOIN person pe ON p.creator_id = pe.id
|
||||||
|
WHERE
|
||||||
|
p.published > ('now'::timestamp - i::interval)
|
||||||
|
AND pe.bot_account = FALSE
|
||||||
|
UNION
|
||||||
|
SELECT
|
||||||
|
pl.person_id,
|
||||||
|
p.community_id
|
||||||
|
FROM
|
||||||
|
post_like pl
|
||||||
|
INNER JOIN post p ON pl.post_id = p.id
|
||||||
|
INNER JOIN person pe ON pl.person_id = pe.id
|
||||||
|
WHERE
|
||||||
|
pl.published > ('now'::timestamp - i::interval)
|
||||||
|
AND pe.bot_account = FALSE
|
||||||
|
UNION
|
||||||
|
SELECT
|
||||||
|
cl.person_id,
|
||||||
|
p.community_id
|
||||||
|
FROM
|
||||||
|
comment_like cl
|
||||||
|
INNER JOIN post p ON cl.post_id = p.id
|
||||||
|
INNER JOIN person pe ON cl.person_id = pe.id
|
||||||
|
WHERE
|
||||||
|
cl.published > ('now'::timestamp - i::interval)
|
||||||
|
AND pe.bot_account = FALSE) a
|
||||||
|
GROUP BY
|
||||||
|
community_id;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Edit site aggregates to include voters and people who have read posts as active users
|
||||||
|
CREATE OR REPLACE FUNCTION site_aggregates_activity (i text)
|
||||||
|
RETURNS integer
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
count_ integer;
|
||||||
|
BEGIN
|
||||||
|
SELECT
|
||||||
|
count(*) INTO count_
|
||||||
|
FROM (
|
||||||
|
SELECT
|
||||||
|
c.creator_id
|
||||||
|
FROM
|
||||||
|
comment c
|
||||||
|
INNER JOIN person pe ON c.creator_id = pe.id
|
||||||
|
WHERE
|
||||||
|
c.published > ('now'::timestamp - i::interval)
|
||||||
|
AND pe.local = TRUE
|
||||||
|
AND pe.bot_account = FALSE
|
||||||
|
UNION
|
||||||
|
SELECT
|
||||||
|
p.creator_id
|
||||||
|
FROM
|
||||||
|
post p
|
||||||
|
INNER JOIN person pe ON p.creator_id = pe.id
|
||||||
|
WHERE
|
||||||
|
p.published > ('now'::timestamp - i::interval)
|
||||||
|
AND pe.local = TRUE
|
||||||
|
AND pe.bot_account = FALSE
|
||||||
|
UNION
|
||||||
|
SELECT
|
||||||
|
pl.person_id
|
||||||
|
FROM
|
||||||
|
post_like pl
|
||||||
|
INNER JOIN person pe ON pl.person_id = pe.id
|
||||||
|
WHERE
|
||||||
|
pl.published > ('now'::timestamp - i::interval)
|
||||||
|
AND pe.local = TRUE
|
||||||
|
AND pe.bot_account = FALSE
|
||||||
|
UNION
|
||||||
|
SELECT
|
||||||
|
cl.person_id
|
||||||
|
FROM
|
||||||
|
comment_like cl
|
||||||
|
INNER JOIN person pe ON cl.person_id = pe.id
|
||||||
|
WHERE
|
||||||
|
cl.published > ('now'::timestamp - i::interval)
|
||||||
|
AND pe.local = TRUE
|
||||||
|
AND pe.bot_account = FALSE) a;
|
||||||
|
RETURN count_;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
Loading…
Reference in a new issue