lemmy/replaceable_schema.sql

275 lines
7 KiB
MySQL
Raw Normal View History

2023-12-23 00:29:04 +00:00
-- This sets up the `r` schema, which contains things that can be safely dropped and replaced instead of being
-- changed using migrations.
2023-12-22 22:47:21 +00:00
--
2023-12-23 00:29:04 +00:00
-- Statements in this file may not create or modify things outside of the `r` schema (indicated by the `r.` prefix),
-- except for these things, which are associated with something other than a schema (usually a table):
2023-12-22 23:16:05 +00:00
-- * A trigger if the function name after `EXECUTE FUNCTION` is in `r` (dropping `r` drops the trigger)
--
2023-12-23 00:29:04 +00:00
-- The default schema is not temporarily set to `r` because it would not affect some things (such as triggers) which
2023-12-22 23:22:53 +00:00
-- makes it hard to tell if the rule above is being followed.
--
2023-12-23 00:29:04 +00:00
-- 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.
2023-12-22 22:47:21 +00:00
BEGIN;
DROP SCHEMA IF EXISTS r CASCADE;
2023-12-22 23:16:05 +00:00
CREATE SCHEMA r;
2023-12-22 22:47:21 +00:00
2023-12-23 18:56:00 +00:00
-- Rank calculations
CREATE OR REPLACE FUNCTION controversy_rank (upvotes numeric, downvotes numeric)
RETURNS float
AS $$
BEGIN
IF downvotes <= 0 OR upvotes <= 0 THEN
RETURN 0;
ELSE
RETURN (upvotes + downvotes) * CASE WHEN upvotes > downvotes THEN
downvotes::float / upvotes::float
ELSE
upvotes::float / downvotes::float
END;
END IF;
END;
$$
LANGUAGE plpgsql
IMMUTABLE;
2023-12-23 16:28:12 +00:00
-- These triggers resolve an item's reports when the item is marked as removed.
2023-12-23 07:07:59 +00:00
2023-12-23 16:34:32 +00:00
CREATE FUNCTION resolve_reports_when_comment_removed ()
RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE
comment_report
SET
resolved = TRUE,
resolver_id = mod_person_id,
updated = now()
FROM
new_removal
WHERE
comment_report.comment_id = new_removal.comment_id AND new_removal.removed;
RETURN NULL;
END
$$;
CREATE TRIGGER resolve_reports
AFTER INSERT ON mod_remove_comment
REFERENCING NEW TABLE AS new_removal
FOR EACH STATEMENT
EXECUTE FUNCTION resolve_reports_when_comment_removed ();
CREATE FUNCTION resolve_reports_when_post_removed ()
RETURNS trigger
2023-12-23 07:07:59 +00:00
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE
post_report
SET
resolved = TRUE,
resolver_id = mod_person_id,
updated = now()
FROM
new_removal
WHERE
2023-12-23 16:34:32 +00:00
post_report.post_id = new_removal.post_id AND new_removal.removed;
2023-12-23 07:07:59 +00:00
RETURN NULL;
END
$$;
CREATE TRIGGER resolve_reports
AFTER INSERT ON mod_remove_post
REFERENCING NEW TABLE AS new_removal
FOR EACH STATEMENT
EXECUTE FUNCTION resolve_reports_when_post_removed ();
2023-12-23 06:08:40 +00:00
-- 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.
2023-12-22 22:47:21 +00:00
2023-12-23 06:27:02 +00:00
CREATE FUNCTION comment_aggregates_from_comment ()
RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
INSERT INTO comment_aggregates (comment_id, published)
SELECT
id,
published
FROM
new_comment;
RETURN NULL;
END
$$;
CREATE TRIGGER aggregates
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
2023-12-22 22:47:21 +00:00
LANGUAGE plpgsql
AS $$
BEGIN
2023-12-23 06:19:56 +00:00
INSERT INTO community_aggregates (community_id, published)
2023-12-22 22:47:21 +00:00
SELECT
community_id,
2023-12-23 06:08:40 +00:00
published
2023-12-22 22:47:21 +00:00
FROM
2023-12-23 06:19:56 +00:00
new_community;
2023-12-22 22:47:21 +00:00
RETURN NULL;
END
$$;
2023-12-23 06:19:56 +00:00
CREATE TRIGGER aggregates
AFTER INSERT ON community
2023-12-23 06:08:40 +00:00
REFERENCING NEW TABLE AS new_community
FOR EACH STATEMENT
2023-12-23 06:19:56 +00:00
EXECUTE FUNCTION r.community_aggregates_from_community ();
2023-12-23 06:48:38 +00:00
CREATE FUNCTION person_aggregates_from_person ()
RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
INSERT INTO person_aggregates (person_id)
SELECT
id,
FROM
new_person;
RETURN NULL;
END
$$;
CREATE TRIGGER aggregates
AFTER INSERT ON person
REFERENCING NEW TABLE AS new_person
FOR EACH STATEMENT
EXECUTE FUNCTION r.person_aggregates_from_person ();
2023-12-23 06:27:02 +00:00
CREATE FUNCTION r.post_aggregates_from_post ()
RETURNS trigger
2023-12-23 06:19:56 +00:00
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
FROM
new_post
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
FOR EACH STATEMENT
EXECUTE FUNCTION r.post_aggregates_from_post ();
2023-12-22 22:47:21 +00:00
2023-12-23 06:54:50 +00:00
CREATE FUNCTION r.site_aggregates_from_site ()
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
2023-12-23 16:28:12 +00:00
INSERT INTO
site_aggregates (site_id)
VALUES
(NEW.id);
2023-12-23 06:54:50 +00:00
RETURN NULL;
END
$$;
CREATE TRIGGER aggregates
AFTER INSERT ON site
2023-12-23 16:28:12 +00:00
FOR EACH ROW
2023-12-23 06:54:50 +00:00
EXECUTE FUNCTION r.site_aggregates_from_site ();
2023-12-23 18:56:00 +00:00
-- These triggers update aggregates in response to votes.
CREATE FUNCTION comment_aggregates_from_like()
RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
WITH
any_like (comment_id, score, added) AS (
SELECT
comment_id,
score,
-1
FROM
old_like
UNION ALL
SELECT
comment_id,
score,
1
FROM
new_like
),
added_to_comment (comment_id, added_upvotes, added_downvotes) AS (
SELECT
comment_id,
sum(added) FILTER (WHERE score = 1),
sum(added) FILTER (WHERE score = -1)
FROM
any_like
GROUP BY
comment_id
)
UPDATE
comment_aggregates
SET
score = score + added_upvotes - added_downvotes,
upvotes = upvotes + added_upvotes,
downvotes = downvotes + added_downvotes,
controversy_rank = controversy_rank (
(upvotes + added_upvotes)::numeric,
(downvotes + added_downvotes)::numeric
)
FROM
added_to_comment
WHERE
comment_aggregates.comment_id = added_to_comment.comment_id;
RETURN NULL;
END
$$;
2023-12-22 22:47:21 +00:00
COMMIT;