From 0f200435d7da4c5756a1dd5d08785b63bee6a7ee Mon Sep 17 00:00:00 2001 From: Dull Bananas Date: Mon, 25 Dec 2023 04:19:37 +0000 Subject: [PATCH] stuff --- .pg_format | 5 + .../down.sql | 316 ++++++++++++++---- .../up.sql | 3 + migrations/up.sql | 34 -- replaceable_schema.sql | 211 +++++------- 5 files changed, 330 insertions(+), 239 deletions(-) create mode 100644 .pg_format rename migrations/{ => 2023-12-25-034523_replaceable-schema}/down.sql (66%) create mode 100644 migrations/2023-12-25-034523_replaceable-schema/up.sql delete mode 100644 migrations/up.sql diff --git a/.pg_format b/.pg_format new file mode 100644 index 000000000..033229f41 --- /dev/null +++ b/.pg_format @@ -0,0 +1,5 @@ +# Keep normal formatting between `BEGIN` and `COMMIT` statements +nogrouping=1 + +# Don't add spaces after % in dollar-quoted function body when using `format` +placeholder=.%. diff --git a/migrations/down.sql b/migrations/2023-12-25-034523_replaceable-schema/down.sql similarity index 66% rename from migrations/down.sql rename to migrations/2023-12-25-034523_replaceable-schema/down.sql index 9cc298fbd..6664d6eb4 100644 --- a/migrations/down.sql +++ b/migrations/2023-12-25-034523_replaceable-schema/down.sql @@ -1,6 +1,7 @@ DROP SCHEMA IF EXISTS r CASCADE; -CREATE FUNCTION comment_aggregates_comment() RETURNS trigger +CREATE FUNCTION comment_aggregates_comment () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -15,7 +16,8 @@ BEGIN END $$; -CREATE FUNCTION comment_aggregates_score() RETURNS trigger +CREATE FUNCTION comment_aggregates_score () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -80,7 +82,8 @@ BEGIN END $$; -CREATE FUNCTION comment_removed_resolve_reports() RETURNS trigger +CREATE FUNCTION comment_removed_resolve_reports () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -96,7 +99,8 @@ BEGIN END $$; -CREATE FUNCTION community_aggregates_comment_count() RETURNS trigger +CREATE FUNCTION community_aggregates_comment_count () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -125,7 +129,8 @@ BEGIN END $$; -CREATE FUNCTION community_aggregates_community() RETURNS trigger +CREATE FUNCTION community_aggregates_community () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -140,7 +145,8 @@ BEGIN END $$; -CREATE FUNCTION community_aggregates_post_count() RETURNS trigger +CREATE FUNCTION community_aggregates_post_count () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -215,19 +221,31 @@ BEGIN END $$; -CREATE FUNCTION community_aggregates_post_count_insert() RETURNS trigger +CREATE FUNCTION community_aggregates_post_count_insert () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN - UPDATE community_aggregates - SET posts = posts + post_group.count - FROM (SELECT community_id, count(*) FROM new_post GROUP BY community_id) post_group - WHERE community_aggregates.community_id = post_group.community_id; + UPDATE + community_aggregates + SET + posts = posts + post_group.count + FROM ( + SELECT + community_id, + count(*) + FROM + new_post + GROUP BY + community_id) post_group +WHERE + community_aggregates.community_id = post_group.community_id; RETURN NULL; END $$; -CREATE FUNCTION community_aggregates_subscriber_count() RETURNS trigger +CREATE FUNCTION community_aggregates_subscriber_count () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -258,7 +276,8 @@ BEGIN END $$; -CREATE FUNCTION person_aggregates_comment_count() RETURNS trigger +CREATE FUNCTION person_aggregates_comment_count () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -281,7 +300,8 @@ BEGIN END $$; -CREATE FUNCTION person_aggregates_comment_score() RETURNS trigger +CREATE FUNCTION person_aggregates_comment_score () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -311,7 +331,8 @@ BEGIN END $$; -CREATE FUNCTION person_aggregates_person() RETURNS trigger +CREATE FUNCTION person_aggregates_person () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -326,7 +347,8 @@ BEGIN END $$; -CREATE FUNCTION person_aggregates_post_count() RETURNS trigger +CREATE FUNCTION person_aggregates_post_count () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -349,19 +371,31 @@ BEGIN END $$; -CREATE FUNCTION person_aggregates_post_insert() RETURNS trigger +CREATE FUNCTION person_aggregates_post_insert () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN - UPDATE person_aggregates - SET post_count = post_count + post_group.count - FROM (SELECT creator_id, count(*) FROM new_post GROUP BY creator_id) post_group - WHERE person_aggregates.person_id = post_group.creator_id; + UPDATE + person_aggregates + SET + post_count = post_count + post_group.count + FROM ( + SELECT + creator_id, + count(*) + FROM + new_post + GROUP BY + creator_id) post_group +WHERE + person_aggregates.person_id = post_group.creator_id; RETURN NULL; END $$; -CREATE FUNCTION person_aggregates_post_score() RETURNS trigger +CREATE FUNCTION person_aggregates_post_score () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -391,7 +425,8 @@ BEGIN END $$; -CREATE FUNCTION post_aggregates_comment_count() RETURNS trigger +CREATE FUNCTION post_aggregates_comment_count () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -444,7 +479,8 @@ BEGIN END $$; -CREATE FUNCTION post_aggregates_featured_community() RETURNS trigger +CREATE FUNCTION post_aggregates_featured_community () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -458,7 +494,8 @@ BEGIN END $$; -CREATE FUNCTION post_aggregates_featured_local() RETURNS trigger +CREATE FUNCTION post_aggregates_featured_local () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -472,7 +509,8 @@ BEGIN END $$; -CREATE FUNCTION post_aggregates_post() RETURNS trigger +CREATE FUNCTION post_aggregates_post () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -484,14 +522,22 @@ BEGIN published, community_id, creator_id, - (SELECT community.instance_id FROM community WHERE community.id = community_id LIMIT 1) - FROM - new_post; + ( + SELECT + community.instance_id + FROM + community + WHERE + community.id = community_id + LIMIT 1) +FROM + new_post; RETURN NULL; END $$; -CREATE FUNCTION post_aggregates_score() RETURNS trigger +CREATE FUNCTION post_aggregates_score () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -556,7 +602,8 @@ BEGIN END $$; -CREATE FUNCTION post_removed_resolve_reports() RETURNS trigger +CREATE FUNCTION post_removed_resolve_reports () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -572,7 +619,8 @@ BEGIN END $$; -CREATE FUNCTION site_aggregates_comment_delete() RETURNS trigger +CREATE FUNCTION site_aggregates_comment_delete () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -590,7 +638,8 @@ BEGIN END $$; -CREATE FUNCTION site_aggregates_comment_insert() RETURNS trigger +CREATE FUNCTION site_aggregates_comment_insert () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -608,7 +657,8 @@ BEGIN END $$; -CREATE FUNCTION site_aggregates_community_insert() RETURNS trigger +CREATE FUNCTION site_aggregates_community_insert () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -626,7 +676,8 @@ BEGIN END $$; -CREATE FUNCTION site_aggregates_person_delete() RETURNS trigger +CREATE FUNCTION site_aggregates_person_delete () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -643,7 +694,8 @@ BEGIN END $$; -CREATE FUNCTION site_aggregates_person_insert() RETURNS trigger +CREATE FUNCTION site_aggregates_person_insert () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -655,7 +707,8 @@ BEGIN END $$; -CREATE FUNCTION site_aggregates_post_delete() RETURNS trigger +CREATE FUNCTION site_aggregates_post_delete () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -673,14 +726,19 @@ BEGIN END $$; -CREATE FUNCTION site_aggregates_post_insert() RETURNS trigger +CREATE FUNCTION site_aggregates_post_insert () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN UPDATE site_aggregates sa SET - posts = posts + (SELECT count(*) FROM new_post) + posts = posts + ( + SELECT + count(*) + FROM + new_post) FROM site s WHERE @@ -689,7 +747,8 @@ BEGIN END $$; -CREATE FUNCTION site_aggregates_post_update() RETURNS trigger +CREATE FUNCTION site_aggregates_post_update () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -707,7 +766,8 @@ BEGIN END $$; -CREATE FUNCTION site_aggregates_site() RETURNS trigger +CREATE FUNCTION site_aggregates_site () + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -729,7 +789,8 @@ BEGIN END $$; -CREATE FUNCTION was_removed_or_deleted(tg_op text, old record, new record) RETURNS boolean +CREATE FUNCTION was_removed_or_deleted (tg_op text, old record, new record) + RETURNS boolean LANGUAGE plpgsql AS $$ BEGIN @@ -747,7 +808,8 @@ BEGIN END $$; -CREATE FUNCTION was_restored_or_created(tg_op text, old record, new record) RETURNS boolean +CREATE FUNCTION was_restored_or_created (tg_op text, old record, new record) + RETURNS boolean LANGUAGE plpgsql AS $$ BEGIN @@ -765,63 +827,169 @@ BEGIN END $$; -CREATE TRIGGER comment_aggregates_comment AFTER INSERT OR DELETE ON comment FOR EACH ROW EXECUTE FUNCTION comment_aggregates_comment(); +CREATE TRIGGER comment_aggregates_comment + AFTER INSERT OR DELETE ON comment + FOR EACH ROW + EXECUTE FUNCTION comment_aggregates_comment (); -CREATE TRIGGER comment_aggregates_score AFTER INSERT OR DELETE ON comment_like FOR EACH ROW EXECUTE FUNCTION comment_aggregates_score(); +CREATE TRIGGER comment_aggregates_score + AFTER INSERT OR DELETE ON comment_like + FOR EACH ROW + EXECUTE FUNCTION comment_aggregates_score (); -CREATE TRIGGER comment_removed_resolve_reports AFTER INSERT ON mod_remove_comment FOR EACH ROW WHEN (new.removed) EXECUTE FUNCTION comment_removed_resolve_reports(); +CREATE TRIGGER comment_removed_resolve_reports + AFTER INSERT ON mod_remove_comment + FOR EACH ROW + WHEN (new.removed) + EXECUTE FUNCTION comment_removed_resolve_reports (); -CREATE TRIGGER community_aggregates_comment_count AFTER INSERT OR DELETE OR UPDATE OF removed, deleted ON comment FOR EACH ROW EXECUTE FUNCTION community_aggregates_comment_count(); +CREATE TRIGGER community_aggregates_comment_count + AFTER INSERT OR DELETE OR UPDATE OF removed, + deleted ON comment + FOR EACH ROW + EXECUTE FUNCTION community_aggregates_comment_count (); -CREATE TRIGGER community_aggregates_community AFTER INSERT OR DELETE ON community FOR EACH ROW EXECUTE FUNCTION community_aggregates_community(); +CREATE TRIGGER community_aggregates_community + AFTER INSERT OR DELETE ON community + FOR EACH ROW + EXECUTE FUNCTION community_aggregates_community (); -CREATE TRIGGER community_aggregates_post_count AFTER DELETE OR UPDATE OF removed, deleted ON post FOR EACH ROW EXECUTE FUNCTION community_aggregates_post_count(); +CREATE TRIGGER community_aggregates_post_count + AFTER DELETE OR UPDATE OF removed, + deleted ON post + FOR EACH ROW + EXECUTE FUNCTION community_aggregates_post_count (); -CREATE TRIGGER community_aggregates_post_count_insert AFTER INSERT ON post REFERENCING NEW TABLE AS new_post FOR EACH STATEMENT EXECUTE FUNCTION community_aggregates_post_count_insert(); +CREATE TRIGGER community_aggregates_post_count_insert + AFTER INSERT ON post REFERENCING NEW TABLE AS new_post + FOR EACH STATEMENT + EXECUTE FUNCTION community_aggregates_post_count_insert (); -CREATE TRIGGER community_aggregates_subscriber_count AFTER INSERT OR DELETE ON community_follower FOR EACH ROW EXECUTE FUNCTION community_aggregates_subscriber_count(); +CREATE TRIGGER community_aggregates_subscriber_count + AFTER INSERT OR DELETE ON community_follower + FOR EACH ROW + EXECUTE FUNCTION community_aggregates_subscriber_count (); -CREATE TRIGGER person_aggregates_comment_count AFTER INSERT OR DELETE OR UPDATE OF removed, deleted ON comment FOR EACH ROW EXECUTE FUNCTION person_aggregates_comment_count(); +CREATE TRIGGER person_aggregates_comment_count + AFTER INSERT OR DELETE OR UPDATE OF removed, + deleted ON comment + FOR EACH ROW + EXECUTE FUNCTION person_aggregates_comment_count (); -CREATE TRIGGER person_aggregates_comment_score AFTER INSERT OR DELETE ON comment_like FOR EACH ROW EXECUTE FUNCTION person_aggregates_comment_score(); +CREATE TRIGGER person_aggregates_comment_score + AFTER INSERT OR DELETE ON comment_like + FOR EACH ROW + EXECUTE FUNCTION person_aggregates_comment_score (); -CREATE TRIGGER person_aggregates_person AFTER INSERT OR DELETE ON person FOR EACH ROW EXECUTE FUNCTION person_aggregates_person(); +CREATE TRIGGER person_aggregates_person + AFTER INSERT OR DELETE ON person + FOR EACH ROW + EXECUTE FUNCTION person_aggregates_person (); -CREATE TRIGGER person_aggregates_post_count AFTER DELETE OR UPDATE OF removed, deleted ON post FOR EACH ROW EXECUTE FUNCTION person_aggregates_post_count(); +CREATE TRIGGER person_aggregates_post_count + AFTER DELETE OR UPDATE OF removed, + deleted ON post + FOR EACH ROW + EXECUTE FUNCTION person_aggregates_post_count (); -CREATE TRIGGER person_aggregates_post_insert AFTER INSERT ON post REFERENCING NEW TABLE AS new_post FOR EACH STATEMENT EXECUTE FUNCTION person_aggregates_post_insert(); +CREATE TRIGGER person_aggregates_post_insert + AFTER INSERT ON post REFERENCING NEW TABLE AS new_post + FOR EACH STATEMENT + EXECUTE FUNCTION person_aggregates_post_insert (); -CREATE TRIGGER person_aggregates_post_score AFTER INSERT OR DELETE ON post_like FOR EACH ROW EXECUTE FUNCTION person_aggregates_post_score(); +CREATE TRIGGER person_aggregates_post_score + AFTER INSERT OR DELETE ON post_like + FOR EACH ROW + EXECUTE FUNCTION person_aggregates_post_score (); -CREATE TRIGGER post_aggregates_comment_count AFTER INSERT OR DELETE OR UPDATE OF removed, deleted ON comment FOR EACH ROW EXECUTE FUNCTION post_aggregates_comment_count(); +CREATE TRIGGER post_aggregates_comment_count + AFTER INSERT OR DELETE OR UPDATE OF removed, + deleted ON comment + FOR EACH ROW + EXECUTE FUNCTION post_aggregates_comment_count (); -CREATE TRIGGER post_aggregates_featured_community AFTER UPDATE ON post FOR EACH ROW WHEN ((old.featured_community IS DISTINCT FROM new.featured_community)) EXECUTE FUNCTION post_aggregates_featured_community(); +CREATE TRIGGER post_aggregates_featured_community + AFTER UPDATE ON post + FOR EACH ROW + WHEN ((old.featured_community IS DISTINCT FROM new.featured_community)) + EXECUTE FUNCTION post_aggregates_featured_community (); -CREATE TRIGGER post_aggregates_featured_local AFTER UPDATE ON post FOR EACH ROW WHEN ((old.featured_local IS DISTINCT FROM new.featured_local)) EXECUTE FUNCTION post_aggregates_featured_local(); +CREATE TRIGGER post_aggregates_featured_local + AFTER UPDATE ON post + FOR EACH ROW + WHEN ((old.featured_local IS DISTINCT FROM new.featured_local)) + EXECUTE FUNCTION post_aggregates_featured_local (); -CREATE TRIGGER post_aggregates_post AFTER INSERT ON post REFERENCING NEW TABLE AS new_post FOR EACH STATEMENT EXECUTE FUNCTION post_aggregates_post(); +CREATE TRIGGER post_aggregates_post + AFTER INSERT ON post REFERENCING NEW TABLE AS new_post + FOR EACH STATEMENT + EXECUTE FUNCTION post_aggregates_post (); -CREATE TRIGGER post_aggregates_score AFTER INSERT OR DELETE ON post_like FOR EACH ROW EXECUTE FUNCTION post_aggregates_score(); +CREATE TRIGGER post_aggregates_score + AFTER INSERT OR DELETE ON post_like + FOR EACH ROW + EXECUTE FUNCTION post_aggregates_score (); -CREATE TRIGGER post_removed_resolve_reports AFTER INSERT ON mod_remove_post FOR EACH ROW WHEN (new.removed) EXECUTE FUNCTION post_removed_resolve_reports(); +CREATE TRIGGER post_removed_resolve_reports + AFTER INSERT ON mod_remove_post + FOR EACH ROW + WHEN (new.removed) + EXECUTE FUNCTION post_removed_resolve_reports (); -CREATE TRIGGER site_aggregates_comment_delete AFTER DELETE OR UPDATE OF removed, deleted ON comment FOR EACH ROW WHEN ((old.local = true)) EXECUTE FUNCTION site_aggregates_comment_delete(); +CREATE TRIGGER site_aggregates_comment_delete + AFTER DELETE OR UPDATE OF removed, + deleted ON comment + FOR EACH ROW + WHEN ((old.local = TRUE)) + EXECUTE FUNCTION site_aggregates_comment_delete (); -CREATE TRIGGER site_aggregates_comment_insert AFTER INSERT OR UPDATE OF removed, deleted ON comment FOR EACH ROW WHEN ((new.local = true)) EXECUTE FUNCTION site_aggregates_comment_insert(); +CREATE TRIGGER site_aggregates_comment_insert + AFTER INSERT OR UPDATE OF removed, + deleted ON comment + FOR EACH ROW + WHEN ((new.local = TRUE)) + EXECUTE FUNCTION site_aggregates_comment_insert (); -CREATE TRIGGER site_aggregates_community_insert AFTER INSERT OR UPDATE OF removed, deleted ON community FOR EACH ROW WHEN ((new.local = true)) EXECUTE FUNCTION site_aggregates_community_insert(); +CREATE TRIGGER site_aggregates_community_insert + AFTER INSERT OR UPDATE OF removed, + deleted ON community + FOR EACH ROW + WHEN ((new.local = TRUE)) + EXECUTE FUNCTION site_aggregates_community_insert (); -CREATE TRIGGER site_aggregates_person_delete AFTER DELETE ON person FOR EACH ROW WHEN ((old.local = true)) EXECUTE FUNCTION site_aggregates_person_delete(); +CREATE TRIGGER site_aggregates_person_delete + AFTER DELETE ON person + FOR EACH ROW + WHEN ((old.local = TRUE)) + EXECUTE FUNCTION site_aggregates_person_delete (); -CREATE TRIGGER site_aggregates_person_insert AFTER INSERT ON person FOR EACH ROW WHEN ((new.local = true)) EXECUTE FUNCTION site_aggregates_person_insert(); +CREATE TRIGGER site_aggregates_person_insert + AFTER INSERT ON person + FOR EACH ROW + WHEN ((new.local = TRUE)) + EXECUTE FUNCTION site_aggregates_person_insert (); -CREATE TRIGGER site_aggregates_post_delete AFTER DELETE OR UPDATE OF removed, deleted ON post FOR EACH ROW WHEN ((old.local = true)) EXECUTE FUNCTION site_aggregates_post_delete(); +CREATE TRIGGER site_aggregates_post_delete + AFTER DELETE OR UPDATE OF removed, + deleted ON post + FOR EACH ROW + WHEN ((old.local = TRUE)) + EXECUTE FUNCTION site_aggregates_post_delete (); -CREATE TRIGGER site_aggregates_post_insert AFTER INSERT ON post REFERENCING NEW TABLE AS new_post FOR EACH STATEMENT EXECUTE FUNCTION site_aggregates_post_insert(); +CREATE TRIGGER site_aggregates_post_insert + AFTER INSERT ON post REFERENCING NEW TABLE AS new_post + FOR EACH STATEMENT + EXECUTE FUNCTION site_aggregates_post_insert (); +CREATE TRIGGER site_aggregates_post_update + AFTER UPDATE OF removed, + deleted ON post + FOR EACH ROW + WHEN ((new.local = TRUE)) + EXECUTE FUNCTION site_aggregates_post_update (); +CREATE TRIGGER site_aggregates_site + AFTER INSERT OR DELETE ON site + FOR EACH ROW + EXECUTE FUNCTION site_aggregates_site (); -CREATE TRIGGER site_aggregates_post_update AFTER UPDATE OF removed, deleted ON post FOR EACH ROW WHEN ((new.local = true)) EXECUTE FUNCTION site_aggregates_post_update(); - - -CREATE TRIGGER site_aggregates_site AFTER INSERT OR DELETE ON site FOR EACH ROW EXECUTE FUNCTION site_aggregates_site(); diff --git a/migrations/2023-12-25-034523_replaceable-schema/up.sql b/migrations/2023-12-25-034523_replaceable-schema/up.sql new file mode 100644 index 000000000..0964a117d --- /dev/null +++ b/migrations/2023-12-25-034523_replaceable-schema/up.sql @@ -0,0 +1,3 @@ +-- 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; + diff --git a/migrations/up.sql b/migrations/up.sql deleted file mode 100644 index 73461895f..000000000 --- a/migrations/up.sql +++ /dev/null @@ -1,34 +0,0 @@ --- 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; - diff --git a/replaceable_schema.sql b/replaceable_schema.sql index a5e423348..d1ede825f 100644 --- a/replaceable_schema.sql +++ b/replaceable_schema.sql @@ -11,7 +11,6 @@ -- If you add something here that depends on something (such as a table) created in a new migration, then down.sql must use -- `CASCADE` when dropping it. This doesn't need to be fixed in old migrations because the "replaceable-schema" migration -- runs `DROP SCHEMA IF EXISTS r CASCADE` in down.sql. - BEGIN; DROP SCHEMA IF EXISTS r CASCADE; @@ -19,7 +18,6 @@ DROP SCHEMA IF EXISTS r CASCADE; CREATE SCHEMA r; -- Rank calculations - CREATE OR REPLACE FUNCTION r.controversy_rank (upvotes numeric, downvotes numeric) RETURNS float AS $$ @@ -57,37 +55,29 @@ CREATE FUNCTION r.combine_transition_tables () $$; -- These triggers resolve an item's reports when the item is marked as removed. - CREATE PROCEDURE r.resolve_reports_when_target_removed (target_name text) - LANGUAGE plpgsql - AS $a$ +LANGUAGE plpgsql +AS $a$ BEGIN - EXECUTE format($b$ - CREATE FUNCTION r.resolve_reports_when_%1$s_removed () - RETURNS trigger + EXECUTE format($b$ CREATE FUNCTION r.resolve_reports_when_%1 $ s_removed ( ) + RETURNS TRIGGER LANGUAGE plpgsql AS $$ - BEGIN - UPDATE - %1$s_report AS report - SET - resolved = TRUE, - resolver_id = mod_person_id, - updated = now() - FROM - new_removal - WHERE - report.%1$s_id = new_removal.%1$a_id AND new_removal.removed; - - RETURN NULL; - END - $$; - - CREATE TRIGGER resolve_reports - AFTER INSERT ON mod_remove_%1$s - REFERENCING NEW TABLE AS new_removal - FOR EACH STATEMENT - EXECUTE FUNCTION r.resolve_reports_when_%1$s_removed (); + BEGIN + UPDATE + %1$s_report AS report + SET + resolved = TRUE, resolver_id = mod_person_id, updated = now() + FROM new_removal + WHERE + report.%1$s_id = new_removal.%1$a_id + AND new_removal.removed; + RETURN NULL; + END $$; + CREATE TRIGGER resolve_reports + AFTER INSERT ON mod_remove_ %1$s REFERENCING NEW TABLE AS new_removal + FOR EACH STATEMENT + EXECUTE FUNCTION r.resolve_reports_when_ %1 $ s_removed ( ); $b$, target_name); END @@ -99,21 +89,8 @@ CALL r.resolve_reports_when_target_removed ('post'); -- 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. - -CALL r.upsert_aggregates ('comment', 'published', NULL); - -CALL r.upsert_aggregates ('community', 'published', NULL); - -CALL r.upsert_aggregates ('person', NULL, NULL); - -CALL r.upsert_aggregates ( - 'post', - 'published, newest_comment_time, newest_comment_time_necro, community_id, creator_id, instance_id, featured_community, featured_local', - 'published AS newest_comment_time, published AS newest_comment_time_necro, (SELECT community.instance_id FROM community WHERE community.id = community_id LIMIT 1) AS instance_id' -); - CREATE FUNCTION r.comment_aggregates_from_comment () - RETURNS trigger + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -123,19 +100,17 @@ BEGIN published FROM new_comment; - RETURN NULL; END $$; CREATE TRIGGER aggregates - AFTER INSERT ON comment - REFERENCING NEW TABLE AS new_comment + AFTER INSERT ON comment REFERENCING NEW TABLE AS new_comment FOR EACH STATEMENT EXECUTE FUNCTION r.comment_aggregates_from_comment (); CREATE FUNCTION r.community_aggregates_from_community () - RETURNS trigger + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -145,19 +120,17 @@ BEGIN published FROM new_community; - RETURN NULL; END $$; CREATE TRIGGER aggregates - AFTER INSERT ON community - REFERENCING NEW TABLE AS new_community + AFTER INSERT ON community REFERENCING NEW TABLE AS new_community FOR EACH STATEMENT EXECUTE FUNCTION r.community_aggregates_from_community (); CREATE FUNCTION r.person_aggregates_from_person () - RETURNS trigger + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN @@ -166,66 +139,62 @@ BEGIN id, FROM new_person; - RETURN NULL; END $$; CREATE TRIGGER aggregates - AFTER INSERT ON person - REFERENCING NEW TABLE AS new_person + AFTER INSERT ON person REFERENCING NEW TABLE AS new_person FOR EACH STATEMENT EXECUTE FUNCTION r.person_aggregates_from_person (); CREATE FUNCTION r.post_aggregates_from_post () - RETURNS trigger + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN INSERT INTO post_aggregates (post_id, published, newest_comment_time, newest_comment_time_necro, community_id, creator_id, instance_id, featured_community, featured_local) SELECT - id, - published, - published, - published, - community_id, - creator_id, - (SELECT community.instance_id FROM community WHERE community.id = community_id LIMIT 1), - featured_community, - featured_local + new_post.id, + new_post.published, + new_post.published, + new_post.published, + new_post.community_id, + new_post.creator_id, + community.instance_id, + new_post.featured_community, + new_post.featured_local FROM new_post - ON CONFLICT DO UPDATE SET - featured_community = excluded.featured_community, - featured_local = excluded.featured_local; - + INNER JOIN community ON community.id = new_post.community_id + ON CONFLICT + DO UPDATE SET + featured_community = excluded.featured_community, + featured_local = excluded.featured_local; RETURN NULL; END $$; CREATE TRIGGER aggregates - AFTER INSERT OR UPDATE OF featured_community, featured_local ON post - REFERENCING NEW TABLE AS new_post + AFTER INSERT OR UPDATE OF featured_community, + featured_local ON post REFERENCING NEW TABLE AS new_post FOR EACH STATEMENT EXECUTE FUNCTION r.post_aggregates_from_post (); CREATE FUNCTION r.site_aggregates_from_site () - RETURNS trigger + RETURNS TRIGGER LANGUAGE plpgsql AS $$ BEGIN -- we only ever want to have a single value in site_aggregate because the site_aggregate triggers update all rows in that table. -- a cleaner check would be to insert it for the local_site but that would break assumptions at least in the tests IF NOT EXISTS ( - SELECT - 1 - FROM - site_aggregates) THEN - INSERT INTO - site_aggregates (site_id) - VALUES - (NEW.id); - + SELECT + 1 + FROM + site_aggregates) THEN + INSERT INTO site_aggregates (site_id) + VALUES (NEW.id); RETURN NULL; END $$; @@ -236,51 +205,36 @@ CREATE TRIGGER aggregates 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$ +LANGUAGE plpgsql +AS $a$ BEGIN - EXECUTE format($b$ - CREATE FUNCTION r.%1$s_aggregates_from_like () - RETURNS trigger + EXECUTE format($b$ CREATE FUNCTION r.%1$s_aggregates_from_like ( ) + RETURNS TRIGGER LANGUAGE plpgsql AS $$ - BEGIN - WITH + BEGIN + WITH -- Update aggregates for target - target_diff (creator_id, score) AS ( - UPDATE - %1$s_aggregates AS target_aggregates + target_diff ( + creator_id, score +) AS ( UPDATE + %1$s_aggregates AS target_aggregates SET - score = score + diff.upvotes - diff.downvotes, - upvotes = upvotes + diff.upvotes, - downvotes = downvotes + diff.downvotes, - controversy_rank = controversy_rank ( - (upvotes + diff.upvotes)::numeric, - (downvotes + diff.downvotes)::numeric - ) + score = score + diff.upvotes - diff.downvotes, upvotes = upvotes + diff.upvotes, downvotes = downvotes + diff.downvotes, controversy_rank = controversy_rank ((upvotes + diff.upvotes)::numeric, (downvotes + diff.downvotes)::numeric) FROM ( SELECT - target_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 - target_id - ) AS diff - WHERE - target_aggregates.comment_id = diff.target_id - RETURNING - %2$s, - diff.upvotes - diff.downvotes - ) - -- Update aggregates for target's creator - UPDATE - person_aggregates - SET - %1$s_score = %1$s_score + diff.score; + target_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 target_id) AS diff + WHERE + target_aggregates.comment_id = diff.target_id + RETURNING + %2$s, diff.upvotes - diff.downvotes) + -- Update aggregates for target's creator + UPDATE + person_aggregates + SET + %1$s_score = %1$s_score + diff.score; FROM ( SELECT creator_id, @@ -288,20 +242,15 @@ BEGIN 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; + 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);