Merge branch 'bliss' of https://github.com/dullbananas/lemmy into bliss

This commit is contained in:
Dull Bananas 2023-12-27 22:42:14 +00:00
commit 94e545fe52
8 changed files with 468 additions and 83 deletions

View file

@ -163,7 +163,7 @@ steps:
DATABASE_URL: postgres://lemmy:password@database:5432/lemmy DATABASE_URL: postgres://lemmy:password@database:5432/lemmy
commands: commands:
- diesel migration run - diesel migration run
- psql -f replaceable_schema.sql $DATABASE_URL - psql -f replaceable_schema.sql
- diesel migration redo - diesel migration redo
when: *slow_check_paths when: *slow_check_paths

View file

@ -1,3 +1,52 @@
-- Drop functions and use `CASCADE` to drop the triggers that use them -- Drop functions and use `CASCADE` to drop the triggers that use them
DROP FUNCTION comment_aggregates_comment, comment_aggregates_score, comment_removed_resolve_reports, community_aggregates_comment_count, community_aggregates_community, community_aggregates_post_count, community_aggregates_post_count_insert, community_aggregates_subscriber_count, person_aggregates_comment_count, person_aggregates_comment_score, person_aggregates_person, person_aggregates_post_count, person_aggregates_post_insert, person_aggregates_post_score, post_aggregates_comment_count, post_aggregates_featured_community, post_aggregates_featured_local, post_aggregates_post, post_aggregates_score, post_removed_resolve_reports, site_aggregates_comment_delete, site_aggregates_comment_insert, site_aggregates_community_insert, site_aggregates_person_delete, site_aggregates_person_insert, site_aggregates_post_delete, site_aggregates_post_insert, site_aggregates_post_update, site_aggregates_site, was_removed_or_deleted, was_restored_or_created CASCADE; DROP FUNCTION comment_aggregates_comment, comment_aggregates_score, comment_removed_resolve_reports, community_aggregates_comment_count, community_aggregates_community, community_aggregates_post_count, community_aggregates_post_count_insert, community_aggregates_subscriber_count, person_aggregates_comment_count, person_aggregates_comment_score, person_aggregates_person, person_aggregates_post_count, person_aggregates_post_insert, person_aggregates_post_score, post_aggregates_comment_count, post_aggregates_featured_community, post_aggregates_featured_local, post_aggregates_post, post_aggregates_score, post_removed_resolve_reports, site_aggregates_comment_delete, site_aggregates_comment_insert, site_aggregates_community_insert, site_aggregates_person_delete, site_aggregates_person_insert, site_aggregates_post_delete, site_aggregates_post_insert, site_aggregates_post_update, site_aggregates_site, was_removed_or_deleted, was_restored_or_created CASCADE;
-- Fix values that might be incorrect because of the old triggers
UPDATE
post_aggregates
SET
featured_local = post.featured_local,
featured_community = post.featured_community
FROM
post
WHERE
post_aggregates.post_id = post.id;
UPDATE
community_aggregates
SET
comments = counted.comments
FROM (
SELECT
community.id AS community_id,
count(*) AS comments
FROM
comment,
WHERE
NOT (comment.deleted
OR comment.removed
OR EXISTS (
SELECT
1
FROM
post
WHERE
post.id = comment.post_id
AND (post.deleted OR post.removed)
))
GROUP BY
community.id) AS counted
WHERE
community_aggregates.community_id = counted.community_id;
UPDATE
site_aggregates
SET
communities = (
SELECT
count(*)
FROM
community
WHERE
local);

View file

@ -45,9 +45,9 @@
## Sobre El Proyecto ## Sobre El Proyecto
| Escritorio | Móvil | | Escritorio | Móvil |
| ---------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------------- | | --------------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------------- |
| ![desktop](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/main_img.webp) | ![mobile](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/mobile_pic.webp) | | ![desktop](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/main_screen_2.webp) | ![mobile](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/mobile_pic.webp) |
[Lemmy](https://github.com/LemmyNet/lemmy) es similar a sitios como [Menéame](https://www.meneame.net/), [Reddit](https://reddit.com), [Lobste.rs](https://lobste.rs), [Raddle](https://raddle.me), o [Hacker News](https://news.ycombinator.com/): te subscribes a los foros que te interesan, publicas enlaces y debates, luego votas y comentas en ellos. Entre bastidores, es muy diferente; cualquiera puede gestionar fácilmente un servidor, y todos estos servidores son federados (piensa en el correo electrónico), y conectados al mismo universo, llamado [Fediverso](https://es.wikipedia.org/wiki/Fediverso). [Lemmy](https://github.com/LemmyNet/lemmy) es similar a sitios como [Menéame](https://www.meneame.net/), [Reddit](https://reddit.com), [Lobste.rs](https://lobste.rs), [Raddle](https://raddle.me), o [Hacker News](https://news.ycombinator.com/): te subscribes a los foros que te interesan, publicas enlaces y debates, luego votas y comentas en ellos. Entre bastidores, es muy diferente; cualquiera puede gestionar fácilmente un servidor, y todos estos servidores son federados (piensa en el correo electrónico), y conectados al mismo universo, llamado [Fediverso](https://es.wikipedia.org/wiki/Fediverso).

View file

@ -47,9 +47,9 @@
## プロジェクトについて ## プロジェクトについて
| デスクトップ | モバイル | | デスクトップ | モバイル |
| ---------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------------- | | --------------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------------- |
| ![desktop](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/main_img.webp) | ![mobile](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/mobile_pic.webp) | | ![desktop](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/main_screen_2.webp) | ![mobile](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/mobile_pic.webp) |
[Lemmy](https://github.com/LemmyNet/lemmy) は、[Reddit](https://reddit.com)、[Lobste.rs](https://lobste.rs)、[Hacker News](https://news.ycombinator.com/) といったサイトに似ています。興味のあるフォーラムを購読してリンクや議論を掲載し、投票したり、コメントしたりしています。誰でも簡単にサーバーを運営することができ、これらのサーバーはすべて連合しており(電子メールを考えてください)、[Fediverse](https://en.wikipedia.org/wiki/Fediverse) と呼ばれる同じ宇宙に接続されています。 [Lemmy](https://github.com/LemmyNet/lemmy) は、[Reddit](https://reddit.com)、[Lobste.rs](https://lobste.rs)、[Hacker News](https://news.ycombinator.com/) といったサイトに似ています。興味のあるフォーラムを購読してリンクや議論を掲載し、投票したり、コメントしたりしています。誰でも簡単にサーバーを運営することができ、これらのサーバーはすべて連合しており(電子メールを考えてください)、[Fediverse](https://en.wikipedia.org/wiki/Fediverse) と呼ばれる同じ宇宙に接続されています。

View file

@ -45,9 +45,9 @@
## О проекте ## О проекте
| Десктоп | Мобильный | | Десктоп | Мобильный |
| ---------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------------- | | --------------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------------- |
| ![desktop](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/main_img.webp) | ![mobile](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/mobile_pic.webp) | | ![desktop](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/main_screen_2.webp) | ![mobile](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/mobile_pic.webp) |
[Lemmy](https://github.com/LemmyNet/lemmy) это аналог таких сайтов как [Reddit](https://reddit.com), [Lobste.rs](https://lobste.rs), или [Hacker News](https://news.ycombinator.com/): вы подписываетесь на форумы, которые вас интересуют , размещаете ссылки и дискутируете, затем голосуете и комментируете их. Однако за кулисами всё совсем по-другому; любой может легко запустить сервер, и все эти серверы объединены (например электронная почта) и подключены к одной вселенной, именуемой [Федиверс](https://ru.wikipedia.org/wiki/Fediverse). [Lemmy](https://github.com/LemmyNet/lemmy) это аналог таких сайтов как [Reddit](https://reddit.com), [Lobste.rs](https://lobste.rs), или [Hacker News](https://news.ycombinator.com/): вы подписываетесь на форумы, которые вас интересуют , размещаете ссылки и дискутируете, затем голосуете и комментируете их. Однако за кулисами всё совсем по-другому; любой может легко запустить сервер, и все эти серверы объединены (например электронная почта) и подключены к одной вселенной, именуемой [Федиверс](https://ru.wikipedia.org/wiki/Fediverse).

View file

@ -47,9 +47,9 @@
## 关于项目 ## 关于项目
| 桌面应用 | 移动应用 | | 桌面应用 | 移动应用 |
| ---------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------------- | | --------------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------------- |
| ![desktop](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/main_img.webp) | ![mobile](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/mobile_pic.webp) | | ![desktop](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/main_screen_2.webp) | ![mobile](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/mobile_pic.webp) |
[Lemmy](https://github.com/LemmyNet/lemmy) 与 [Reddit](https://reddit.com)、[Lobste.rs](https://lobste.rs) 或 [Hacker News](https://news.ycombinator.com/) 等网站类似你可以订阅你感兴趣的论坛发布链接和讨论然后进行投票或评论。但在幕后Lemmy 和他们不同——任何人都可以很容易地运行一个服务器,所有服务器都是联邦式的(想想电子邮件),并连接到 [联邦宇宙](https://zh.wikipedia.org/wiki/%E8%81%94%E9%82%A6%E5%AE%87%E5%AE%99)。 [Lemmy](https://github.com/LemmyNet/lemmy) 与 [Reddit](https://reddit.com)、[Lobste.rs](https://lobste.rs) 或 [Hacker News](https://news.ycombinator.com/) 等网站类似你可以订阅你感兴趣的论坛发布链接和讨论然后进行投票或评论。但在幕后Lemmy 和他们不同——任何人都可以很容易地运行一个服务器,所有服务器都是联邦式的(想想电子邮件),并连接到 [联邦宇宙](https://zh.wikipedia.org/wiki/%E8%81%94%E9%82%A6%E5%AE%87%E5%AE%99)。

View file

@ -48,9 +48,9 @@
## 關於專案 ## 關於專案
| 桌面設備 | 行動裝置 | | 桌面設備 | 行動裝置 |
| ---------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------------- | | --------------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------------------------------- |
| ![desktop](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/main_img.webp) | ![mobile](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/mobile_pic.webp) | | ![desktop](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/main_screen_2.webp) | ![mobile](https://raw.githubusercontent.com/LemmyNet/joinlemmy-site/main/src/assets/images/mobile_pic.webp) |
[Lemmy](https://github.com/LemmyNet/lemmy) 與 [Reddit](https://reddit.com)、[Lobste.rs](https://lobste.rs) 或 [Hacker News](https://news.ycombinator.com/) 等網站類似你可以訂閱你感興趣的論壇釋出連結和討論然後進行投票或評論。但在幕後Lemmy 和他們不同——任何人都可以很容易地架設一個伺服器,所有伺服器都是聯邦式的(想想電子郵件),並與 [聯邦宇宙](https://zh.wikipedia.org/wiki/%E8%81%94%E9%82%A6%E5%AE%87%E5%AE%99) 互聯。 [Lemmy](https://github.com/LemmyNet/lemmy) 與 [Reddit](https://reddit.com)、[Lobste.rs](https://lobste.rs) 或 [Hacker News](https://news.ycombinator.com/) 等網站類似你可以訂閱你感興趣的論壇釋出連結和討論然後進行投票或評論。但在幕後Lemmy 和他們不同——任何人都可以很容易地架設一個伺服器,所有伺服器都是聯邦式的(想想電子郵件),並與 [聯邦宇宙](https://zh.wikipedia.org/wiki/%E8%81%94%E9%82%A6%E5%AE%87%E5%AE%99) 互聯。

View file

@ -18,8 +18,10 @@ DROP SCHEMA IF EXISTS r CASCADE;
CREATE SCHEMA r; CREATE SCHEMA r;
-- Rank calculations -- Rank calculations
CREATE OR REPLACE FUNCTION r.controversy_rank (upvotes numeric, downvotes numeric) CREATE FUNCTION r.controversy_rank (upvotes numeric, downvotes numeric)
RETURNS float RETURNS float
LANGUAGE plpgsql
IMMUTABLE PARALLEL SAFE
AS $$ AS $$
BEGIN BEGIN
IF downvotes <= 0 OR upvotes <= 0 THEN IF downvotes <= 0 OR upvotes <= 0 THEN
@ -32,9 +34,7 @@ BEGIN
END; END;
END IF; END IF;
END; END;
$$ $$;
LANGUAGE plpgsql
IMMUTABLE;
-- Selects both old and new rows in a trigger and allows using `sum(count_diff)` to get the number to add to a count -- Selects both old and new rows in a trigger and allows using `sum(count_diff)` to get the number to add to a count
CREATE FUNCTION r.combine_transition_tables () CREATE FUNCTION r.combine_transition_tables ()
@ -54,38 +54,415 @@ CREATE FUNCTION r.combine_transition_tables ()
new_table; new_table;
$$; $$;
-- These triggers resolve an item's reports when the item is marked as removed. -- Define functions
CREATE PROCEDURE r.resolve_reports_when_target_removed (target_name text) CREATE FUNCTION r.creator_id_from_post_aggregates (agg post_aggregates)
RETURNS int
SELECT
creator_id
FROM
agg;
CREATE FUNCTION r.creator_id_from_comment_aggregates (agg comment_aggregates)
RETURNS int
SELECT
creator_id
FROM
comment
WHERE
comment.id = agg.comment_id LIMIT 1;
-- Create triggers for both post and comments
CREATE PROCEDURE r.post_or_comment (thing_type text)
LANGUAGE plpgsql LANGUAGE plpgsql
AS $a$ AS $a$
BEGIN BEGIN
EXECUTE format($b$ CREATE FUNCTION r.resolve_reports_when_%1$s_removed ( ) EXECUTE replace($b$
-- When a thing is removed, resolve its reports
CREATE FUNCTION r.resolve_reports_when_thing_removed ( )
RETURNS TRIGGER RETURNS TRIGGER
LANGUAGE plpgsql LANGUAGE plpgsql
AS $$ AS $$
BEGIN BEGIN
UPDATE UPDATE
%1$s_report AS report thing_report
SET SET
resolved = TRUE, resolver_id = mod_person_id, updated = now() resolved = TRUE, resolver_id = first_removal.mod_person_id, updated = first_removal.when_
FROM new_removal FROM ( SELECT
thing_id,
min(when_) AS when_
FROM new_removal
WHERE
new_removal.removed
GROUP BY
thing_id) AS first_removal
WHERE WHERE
report.%1$s_id = new_removal.%1$s_id report.thing_id = first_removal.thing_id
AND new_removal.removed; AND NOT report.resolved
AND COALESCE(report.updated < first_removal.when_, TRUE);
RETURN NULL; RETURN NULL;
END $$; END $$;
CREATE TRIGGER resolve_reports CREATE TRIGGER resolve_reports
AFTER INSERT ON mod_remove_%1$s REFERENCING NEW TABLE AS new_removal AFTER INSERT ON mod_remove_thing REFERENCING NEW TABLE AS new_removal
FOR EACH STATEMENT FOR EACH STATEMENT
EXECUTE FUNCTION r.resolve_reports_when_%1$s_removed ( ); EXECUTE FUNCTION r.resolve_reports_when_thing_removed ( );
-- When a thing gets a vote, update its aggregates and its creator's aggregates
CREATE FUNCTION r.thing_aggregates_from_like ( )
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
WITH thing_diff AS (
UPDATE
thing_aggregates AS a
SET
score = a.score + diff.upvotes - diff.downvotes,
upvotes = a.upvotes + diff.upvotes,
downvotes = a.downvotes + diff.downvotes,
controversy_rank = controversy_rank ((a.upvotes + diff.upvotes)::numeric, (a.downvotes + diff.downvotes)::numeric)
FROM (
SELECT
thing_id,
sum(count_diff) FILTER (WHERE score = 1) AS upvotes,
sum(count_diff) FILTER (WHERE score != 1) AS downvotes
FROM
r.combine_transition_tables ()
GROUP BY
thing_id) AS diff
WHERE
a.thing_id = diff.thing_id
RETURNING
creator_id_from_thing_aggregates (a.*) AS creator_id,
diff.upvotes - diff.downvotes AS score)
UPDATE
person_aggregates AS a
SET
thing_score = a.thing_score + diff.score
FROM (
SELECT
creator_id,
sum(score) AS score
FROM
target_diff
GROUP BY
creator_id) AS diff
WHERE
a.person_id = diff.creator_id;
RETURN NULL;
END $$;
CREATE TRIGGER aggregates
AFTER INSERT OR DELETE OR UPDATE OF score ON thing_like REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_aggregates_from_like;
$b$, $b$,
target_name); 'thing',
thing_type);
END END
$a$; $a$;
CALL r.resolve_reports_when_target_removed ('comment'); CALL r.post_or_comment ('post');
CALL r.resolve_reports_when_target_removed ('post'); CALL r.post_or_comment ('comment');
-- Create triggers that update counts in parent aggregates
CREATE FUNCTION r.parent_aggregates_from_comment ()
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
WITH comment_group AS (
SELECT
post_id,
creator_id,
local,
sum(count_diff) AS comments,
FROM
combine_transition_tables ()
WHERE
NOT (deleted
OR removed)
GROUP BY
GROUPING SETS (post_id,
creator_id,
local)
),
unused_person_aggregates_update_result AS (
UPDATE
person_aggregates AS a
SET
comment_count = a.comment_count + comment_group.comments
FROM
comment_group
WHERE
a.person_id = comment_group.creator_id
),
unused_site_aggregates_update_result AS (
UPDATE
site_aggregates AS a
SET
comments = a.comments + comment_group.comments
FROM
comment_group
WHERE
comment_group.local
),
post_diff AS (
UPDATE
post_aggregates AS a
SET
comments = a.comments + comment_group.comments,
newest_comment_time = GREATEST (a.newest_comment_time, (
SELECT
max(published)
FROM new_table AS new_comment
WHERE
a.post_id = new_comment.post_id)
LIMIT 1),
newest_comment_time_necro = GREATEST (a.newest_comment_time_necro, (
SELECT
max(published)
FROM new_table AS new_comment
WHERE
a.post_id = new_comment.post_id
-- Ignore comments from the post's creator
AND a.creator_id != new_comment.creator_id
-- Ignore comments on old posts
AND a.published > (new_comment.published - '2 days'::interval)
LIMIT 1))
FROM
comment_group,
LATERAL (
SELECT
*
FROM
post
WHERE
a.post_id = post.id
LIMIT 1) AS post
WHERE
a.post_id = comment_group.post_id
RETURNING
a.community_id,
diff.comments,
NOT (post.deleted
OR post.removed) AS include_in_community_aggregates)
UPDATE
community_aggregates AS a
SET
comments = a.comments + diff.comments
FROM (
SELECT
community_id,
sum(comments)
FROM
post_diff
WHERE
post_diff.include_in_community_aggregates
GROUP BY
community_id) AS diff
WHERE
a.community_id = diff.community_id;
RETURN NULL;
END
$$;
CREATE TRIGGER parent_aggregates
AFTER INSERT OR DELETE OR UPDATE OF deleted,
removed ON comment REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.parent_aggregates_from_comment ();
CREATE FUNCTION r.parent_aggregates_from_post ()
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
WITH post_group AS (
SELECT
community_id,
creator_id,
local,
sum(count_diff) AS posts,
FROM
combine_transition_tables ()
WHERE
NOT (deleted
OR removed)
GROUP BY
GROUPING SETS (community_id,
creator_id,
local)
),
unused_person_aggregates_update_result AS (
UPDATE
person_aggregates AS a
SET
post_count = a.post_count + post_group.posts
FROM
post_group
WHERE
a.person_id = post_group.creator_id
),
unused_site_aggregates_update_result AS (
UPDATE
site_aggregates AS a
SET
posts = a.posts + post_group.posts
FROM
post_group
WHERE
post_group.local)
UPDATE
community_aggregates AS a
SET
posts = a.posts + post_group.posts
FROM
post_group
WHERE
a.community_id = post_group.community_id;
RETURN NULL;
END
$$;
CREATE TRIGGER parent_aggregates
AFTER INSERT OR DELETE OR UPDATE OF deleted,
removed ON comment REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.parent_aggregates_from_comment ();
CREATE FUNCTION site_aggregates_from_community ()
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE
site_aggregates AS a
SET
communities = a.communities + diff.communities
FROM (
SELECT
sum(change_diff) AS communities
FROM
combine_transition_tables ()
WHERE
local
AND NOT (deleted
OR removed)) AS diff;
RETURN NULL;
$$;
CREATE TRIGGER site_aggregates
AFTER INSERT OR DELETE OR UPDATE OF deleted,
removed ON community REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.site_aggregates_from_community ();
CREATE FUNCTION site_aggregates_from_person ()
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE
site_aggregates AS a
SET
users = a.users + diff.users
FROM (
SELECT
sum(change_diff) AS users
FROM
combine_transition_tables ()
WHERE
local) AS diff;
RETURN NULL;
$$;
CREATE TRIGGER site_aggregates
AFTER INSERT OR DELETE ON person REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.site_aggregates_from_person ();
-- For community_aggregates.comments, don't include comments of deleted or removed posts
CREATE FUNCTION r.update_comment_count_from_post ()
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE
community_aggregates AS a
SET
comments = a.comments + diff.comments
FROM (
SELECT
old_post.community_id,
sum((
CASE WHEN new_post.deleted
AND new_post.removed THEN
-1
ELSE
1
END) * post_aggregates.comments) AS comments
FROM
new_post
INNER JOIN old_post ON new_post.id = old_post.id
AND (new_post.deleted
AND new_post.removed) != (old_post.deleted
AND old_post.removed),
LATERAL (
SELECT
*
FROM
post_aggregates
WHERE
post_id = new_post.id
LIMIT 1) AS post_aggregates
GROUP BY
old_post.community_id) AS diff
WHERE
a.community_id = diff.community_id;
RETURN NULL;
$$;
CREATE TRIGGER comment_count
AFTER UPDATE OF deleted,
removed ON post REFERENCING OLD TABLE AS old_post NEW TABLE AS new_post
FOR EACH STATEMENT
EXECUTE FUNCTION r.update_comment_count_from_post ();
-- Count subscribers for local communities
CREATE FUNCTION r.community_aggregates_from_subscriber ()
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE
community_aggregates AS a
SET
subscriber = a.subscribers + diff.subscribers
FROM (
SELECT
community_id,
sum(count_diff) AS subscribers
FROM
combine_transition_tables ()
WHERE (
SELECT
local
FROM
community
WHERE
community.id = community_id
LIMIT 1)
GROUP BY
community_id) AS diff
WHERE
a.community_id = diff.community_id;
RETURN NULL;
END
$$;
CREATE TRIGGER community_aggregates
AFTER INSERT OR DELETE ON community_follower REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.community_aggregates_from_subscriber ();
-- These triggers create and update rows in each aggregates table to match its associated table's rows. -- These triggers create and update rows in each aggregates table to match its associated table's rows.
-- Deleting rows and updating IDs are already handled by `CASCADE` in foreign key constraints. -- Deleting rows and updating IDs are already handled by `CASCADE` in foreign key constraints.
@ -165,8 +542,15 @@ BEGIN
new_post.featured_community, new_post.featured_community,
new_post.featured_local new_post.featured_local
FROM FROM
new_post new_post,
INNER JOIN community ON community.id = new_post.community_id LATERAL (
SELECT
*
FROM
community
WHERE
community.id = new_post.community_id
LIMIT 1) AS community,
ON CONFLICT ON CONFLICT
DO UPDATE SET DO UPDATE SET
featured_community = excluded.featured_community, featured_community = excluded.featured_community,
@ -204,53 +588,5 @@ CREATE TRIGGER aggregates
FOR EACH ROW FOR EACH ROW
EXECUTE FUNCTION r.site_aggregates_from_site (); EXECUTE FUNCTION r.site_aggregates_from_site ();
-- These triggers update aggregates in response to votes.
CREATE PROCEDURE r.aggregates_from_like (target_name text, creator_id_getter text)
LANGUAGE plpgsql
AS $a$
BEGIN
EXECUTE format($b$ CREATE FUNCTION r.%1$s_aggregates_from_like ( )
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
-- Update aggregates for target, then update aggregates for target's creator
WITH target_diff AS ( UPDATE
%1$s_aggregates
SET
(score, upvotes, downvotes, controversy_rank) = (score + diff.upvotes - diff.downvotes, upvotes + diff.upvotes, downvotes + diff.downvotes, controversy_rank ((upvotes + diff.upvotes)::numeric, (downvotes + diff.downvotes)::numeric))
FROM (
SELECT
%1$s_id, sum(count_diff) FILTER (WHERE score = 1) AS upvotes, sum(count_diff) FILTER (WHERE score <> 1) AS downvotes FROM r.combine_transition_tables ()
GROUP BY %1$s_id) AS diff
WHERE
%1$s_aggregates.%1 $ s_id = diff.%1$s_id
RETURNING
%2$s AS creator_id, diff.upvotes - diff.downvotes AS score)
UPDATE
person_aggregates
SET
%1$s_score = %1$s_score + diff.sum FROM (
SELECT
creator_id, sum(score)
FROM target_diff GROUP BY creator_id) AS diff
WHERE
person_aggregates.person_id = diff.creator_id;
RETURN NULL;
END $$;
CREATE TRIGGER aggregates
AFTER INSERT OR DELETE OR UPDATE OF score ON %1$s_like REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table
FOR EACH STATEMENT
EXECUTE FUNCTION r.%1$s_aggregates_from_like;
$b$,
target_name,
creator_id_getter);
END
$a$;
CALL r.aggregates_from_like ('comment', '(SELECT creator_id FROM comment WHERE comment.id = target_aggregates.comment_id LIMIT 1)');
CALL r.aggregates_from_like ('post', 'target_aggregates.creator_id');
COMMIT; COMMIT;