diff --git a/crates/db_schema/replaceable_schema/utils.sql b/crates/db_schema/replaceable_schema/utils.sql index c766d25f2..0c7f42ff2 100644 --- a/crates/db_schema/replaceable_schema/utils.sql +++ b/crates/db_schema/replaceable_schema/utils.sql @@ -151,3 +151,118 @@ DECLARE END; $a$; +-- Edit community aggregates to include voters as active users +CREATE OR REPLACE FUNCTION r.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 comment c ON cl.comment_id = c.id + INNER JOIN post p ON c.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 r.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; +$$; + diff --git a/migrations/2024-11-12-090437_move-triggers/down.sql b/migrations/2024-11-12-090437_move-triggers/down.sql new file mode 100644 index 000000000..3607679bc --- /dev/null +++ b/migrations/2024-11-12-090437_move-triggers/down.sql @@ -0,0 +1,115 @@ +-- 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 comment c ON cl.comment_id = comment.id + INNER JOIN post p ON comment.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; +$$; + diff --git a/migrations/2024-11-12-090437_move-triggers/up.sql b/migrations/2024-11-12-090437_move-triggers/up.sql new file mode 100644 index 000000000..e7b2bd49d --- /dev/null +++ b/migrations/2024-11-12-090437_move-triggers/up.sql @@ -0,0 +1,2 @@ +DROP FUNCTION community_aggregates_activity, site_aggregates_activity CASCADE; + diff --git a/src/scheduled_tasks.rs b/src/scheduled_tasks.rs index ae6187a53..971a970c0 100644 --- a/src/scheduled_tasks.rs +++ b/src/scheduled_tasks.rs @@ -393,7 +393,7 @@ async fn active_counts(pool: &mut DbPool<'_>) { for i in &intervals { let update_site_stmt = format!( - "update site_aggregates set users_active_{} = (select * from site_aggregates_activity('{}')) where site_id = 1", + "update site_aggregates set users_active_{} = (select * from r.site_aggregates_activity('{}')) where site_id = 1", i.1, i.0 ); sql_query(update_site_stmt) @@ -402,7 +402,7 @@ async fn active_counts(pool: &mut DbPool<'_>) { .map_err(|e| error!("Failed to update site stats: {e}")) .ok(); - let update_community_stmt = format!("update community_aggregates ca set users_active_{} = mv.count_ from community_aggregates_activity('{}') mv where ca.community_id = mv.community_id_", i.1, i.0); + let update_community_stmt = format!("update community_aggregates ca set users_active_{} = mv.count_ from r.community_aggregates_activity('{}') mv where ca.community_id = mv.community_id_", i.1, i.0); sql_query(update_community_stmt) .execute(&mut conn) .await