lemmy/migrations/2021-08-16-004209_fix_remove_bots_from_aggregates/up.sql
Dessalines be1389420b
Adding SQL format checking via pg_format / pgFormatter (#3740)
* SQL format checking, 1.

* SQL format checking, 2.

* SQL format checking, 3.

* SQL format checking, 4.

* SQL format checking, 5.

* Running pg_format

* Getting rid of comment.

* Upping pg_format version.

* Using git ls-files for sql format check.

* Fixing sql lints.

* Addressing PR comments.
2023-08-02 12:44:51 -04:00

73 lines
1.8 KiB
PL/PgSQL

-- Make sure bots aren't included in aggregate counts
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;
$$;