mirror of
https://github.com/LemmyNet/lemmy.git
synced 2024-10-01 01:36:12 -04:00
stuff (#21)
This commit is contained in:
parent
2f3a7abe6b
commit
172a64fff4
5
.pg_format
Normal file
5
.pg_format
Normal file
@ -0,0 +1,5 @@
|
||||
# Keep normal formatting between `BEGIN` and `COMMIT` statements
|
||||
nogrouping=1
|
||||
|
||||
# Don't add whitespace around % (used for `format`) in dollar-quoted function body
|
||||
placeholder=[a-zA-Z0-9_\\.]*%[a-zA-Z0-9_\\.]*
|
@ -10,8 +10,9 @@ variables:
|
||||
- "src/**"
|
||||
- "**/Cargo.toml"
|
||||
- "Cargo.lock"
|
||||
# database migrations
|
||||
# sql code
|
||||
- "migrations/**"
|
||||
- "replaceable_schema.sql"
|
||||
# typescript tests
|
||||
- "api_tests/**"
|
||||
# config files and scripts used by ci
|
||||
@ -162,6 +163,7 @@ steps:
|
||||
DATABASE_URL: postgres://lemmy:password@database:5432/lemmy
|
||||
commands:
|
||||
- diesel migration run
|
||||
- psql -f replaceable_schema.sql
|
||||
- diesel migration redo
|
||||
when: *slow_check_paths
|
||||
|
||||
|
@ -10,6 +10,7 @@ use chrono::{DateTime, Utc};
|
||||
use deadpool::Runtime;
|
||||
use diesel::{
|
||||
backend::Backend,
|
||||
connection::SimpleConnection,
|
||||
deserialize::FromSql,
|
||||
helper_types::AsExprOf,
|
||||
pg::Pg,
|
||||
@ -284,6 +285,9 @@ fn run_migrations(db_url: &str) {
|
||||
let _ = &mut conn
|
||||
.run_pending_migrations(MIGRATIONS)
|
||||
.unwrap_or_else(|e| panic!("Couldn't run DB Migrations: {e}"));
|
||||
conn
|
||||
.batch_execute(include_str!("../../../replaceable_schema.sql"))
|
||||
.expect("Couldn't run replaceable_schema.sql");
|
||||
info!("Database migrations complete.");
|
||||
}
|
||||
|
||||
|
995
migrations/2023-12-25-034523_replaceable-schema/down.sql
Normal file
995
migrations/2023-12-25-034523_replaceable-schema/down.sql
Normal file
@ -0,0 +1,995 @@
|
||||
DROP SCHEMA IF EXISTS r CASCADE;
|
||||
|
||||
CREATE FUNCTION comment_aggregates_comment ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'INSERT') THEN
|
||||
INSERT INTO comment_aggregates (comment_id, published)
|
||||
VALUES (NEW.id, NEW.published);
|
||||
ELSIF (TG_OP = 'DELETE') THEN
|
||||
DELETE FROM comment_aggregates
|
||||
WHERE comment_id = OLD.id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION comment_aggregates_score ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'INSERT') THEN
|
||||
UPDATE
|
||||
comment_aggregates ca
|
||||
SET
|
||||
score = score + NEW.score,
|
||||
upvotes = CASE WHEN NEW.score = 1 THEN
|
||||
upvotes + 1
|
||||
ELSE
|
||||
upvotes
|
||||
END,
|
||||
downvotes = CASE WHEN NEW.score = - 1 THEN
|
||||
downvotes + 1
|
||||
ELSE
|
||||
downvotes
|
||||
END,
|
||||
controversy_rank = controversy_rank (ca.upvotes + CASE WHEN NEW.score = 1 THEN
|
||||
1
|
||||
ELSE
|
||||
0
|
||||
END::numeric, ca.downvotes + CASE WHEN NEW.score = - 1 THEN
|
||||
1
|
||||
ELSE
|
||||
0
|
||||
END::numeric)
|
||||
WHERE
|
||||
ca.comment_id = NEW.comment_id;
|
||||
ELSIF (TG_OP = 'DELETE') THEN
|
||||
-- Join to comment because that comment may not exist anymore
|
||||
UPDATE
|
||||
comment_aggregates ca
|
||||
SET
|
||||
score = score - OLD.score,
|
||||
upvotes = CASE WHEN OLD.score = 1 THEN
|
||||
upvotes - 1
|
||||
ELSE
|
||||
upvotes
|
||||
END,
|
||||
downvotes = CASE WHEN OLD.score = - 1 THEN
|
||||
downvotes - 1
|
||||
ELSE
|
||||
downvotes
|
||||
END,
|
||||
controversy_rank = controversy_rank (ca.upvotes + CASE WHEN NEW.score = 1 THEN
|
||||
1
|
||||
ELSE
|
||||
0
|
||||
END::numeric, ca.downvotes + CASE WHEN NEW.score = - 1 THEN
|
||||
1
|
||||
ELSE
|
||||
0
|
||||
END::numeric)
|
||||
FROM
|
||||
comment c
|
||||
WHERE
|
||||
ca.comment_id = c.id
|
||||
AND ca.comment_id = OLD.comment_id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION comment_removed_resolve_reports ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE
|
||||
comment_report
|
||||
SET
|
||||
resolved = TRUE,
|
||||
resolver_id = NEW.mod_person_id,
|
||||
updated = now()
|
||||
WHERE
|
||||
comment_report.comment_id = NEW.comment_id;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION community_aggregates_comment_count ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (was_restored_or_created (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
community_aggregates ca
|
||||
SET
|
||||
comments = comments + 1
|
||||
FROM
|
||||
post p
|
||||
WHERE
|
||||
p.id = NEW.post_id
|
||||
AND ca.community_id = p.community_id;
|
||||
ELSIF (was_removed_or_deleted (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
community_aggregates ca
|
||||
SET
|
||||
comments = comments - 1
|
||||
FROM
|
||||
post p
|
||||
WHERE
|
||||
p.id = OLD.post_id
|
||||
AND ca.community_id = p.community_id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION community_aggregates_community ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'INSERT') THEN
|
||||
INSERT INTO community_aggregates (community_id, published)
|
||||
VALUES (NEW.id, NEW.published);
|
||||
ELSIF (TG_OP = 'DELETE') THEN
|
||||
DELETE FROM community_aggregates
|
||||
WHERE community_id = OLD.id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION community_aggregates_post_count ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (was_restored_or_created (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
community_aggregates
|
||||
SET
|
||||
posts = posts + 1
|
||||
WHERE
|
||||
community_id = NEW.community_id;
|
||||
IF (TG_OP = 'UPDATE') THEN
|
||||
-- Post was restored, so restore comment counts as well
|
||||
UPDATE
|
||||
community_aggregates ca
|
||||
SET
|
||||
posts = coalesce(cd.posts, 0),
|
||||
comments = coalesce(cd.comments, 0)
|
||||
FROM (
|
||||
SELECT
|
||||
c.id,
|
||||
count(DISTINCT p.id) AS posts,
|
||||
count(DISTINCT ct.id) AS comments
|
||||
FROM
|
||||
community c
|
||||
LEFT JOIN post p ON c.id = p.community_id
|
||||
AND p.deleted = 'f'
|
||||
AND p.removed = 'f'
|
||||
LEFT JOIN comment ct ON p.id = ct.post_id
|
||||
AND ct.deleted = 'f'
|
||||
AND ct.removed = 'f'
|
||||
WHERE
|
||||
c.id = NEW.community_id
|
||||
GROUP BY
|
||||
c.id) cd
|
||||
WHERE
|
||||
ca.community_id = NEW.community_id;
|
||||
END IF;
|
||||
ELSIF (was_removed_or_deleted (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
community_aggregates
|
||||
SET
|
||||
posts = posts - 1
|
||||
WHERE
|
||||
community_id = OLD.community_id;
|
||||
-- Update the counts if the post got deleted
|
||||
UPDATE
|
||||
community_aggregates ca
|
||||
SET
|
||||
posts = coalesce(cd.posts, 0),
|
||||
comments = coalesce(cd.comments, 0)
|
||||
FROM (
|
||||
SELECT
|
||||
c.id,
|
||||
count(DISTINCT p.id) AS posts,
|
||||
count(DISTINCT ct.id) AS comments
|
||||
FROM
|
||||
community c
|
||||
LEFT JOIN post p ON c.id = p.community_id
|
||||
AND p.deleted = 'f'
|
||||
AND p.removed = 'f'
|
||||
LEFT JOIN comment ct ON p.id = ct.post_id
|
||||
AND ct.deleted = 'f'
|
||||
AND ct.removed = 'f'
|
||||
WHERE
|
||||
c.id = OLD.community_id
|
||||
GROUP BY
|
||||
c.id) cd
|
||||
WHERE
|
||||
ca.community_id = OLD.community_id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
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;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION community_aggregates_subscriber_count ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'INSERT') THEN
|
||||
UPDATE
|
||||
community_aggregates
|
||||
SET
|
||||
subscribers = subscribers + 1
|
||||
FROM
|
||||
community
|
||||
WHERE
|
||||
community.id = community_id
|
||||
AND community.local
|
||||
AND community_id = NEW.community_id;
|
||||
ELSIF (TG_OP = 'DELETE') THEN
|
||||
UPDATE
|
||||
community_aggregates
|
||||
SET
|
||||
subscribers = subscribers - 1
|
||||
FROM
|
||||
community
|
||||
WHERE
|
||||
community.id = community_id
|
||||
AND community.local
|
||||
AND community_id = OLD.community_id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION person_aggregates_comment_count ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (was_restored_or_created (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
person_aggregates
|
||||
SET
|
||||
comment_count = comment_count + 1
|
||||
WHERE
|
||||
person_id = NEW.creator_id;
|
||||
ELSIF (was_removed_or_deleted (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
person_aggregates
|
||||
SET
|
||||
comment_count = comment_count - 1
|
||||
WHERE
|
||||
person_id = OLD.creator_id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION person_aggregates_comment_score ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'INSERT') THEN
|
||||
-- Need to get the post creator, not the voter
|
||||
UPDATE
|
||||
person_aggregates ua
|
||||
SET
|
||||
comment_score = comment_score + NEW.score
|
||||
FROM
|
||||
comment c
|
||||
WHERE
|
||||
ua.person_id = c.creator_id
|
||||
AND c.id = NEW.comment_id;
|
||||
ELSIF (TG_OP = 'DELETE') THEN
|
||||
UPDATE
|
||||
person_aggregates ua
|
||||
SET
|
||||
comment_score = comment_score - OLD.score
|
||||
FROM
|
||||
comment c
|
||||
WHERE
|
||||
ua.person_id = c.creator_id
|
||||
AND c.id = OLD.comment_id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION person_aggregates_person ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'INSERT') THEN
|
||||
INSERT INTO person_aggregates (person_id)
|
||||
VALUES (NEW.id);
|
||||
ELSIF (TG_OP = 'DELETE') THEN
|
||||
DELETE FROM person_aggregates
|
||||
WHERE person_id = OLD.id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION person_aggregates_post_count ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (was_restored_or_created (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
person_aggregates
|
||||
SET
|
||||
post_count = post_count + 1
|
||||
WHERE
|
||||
person_id = NEW.creator_id;
|
||||
ELSIF (was_removed_or_deleted (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
person_aggregates
|
||||
SET
|
||||
post_count = post_count - 1
|
||||
WHERE
|
||||
person_id = OLD.creator_id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
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;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION person_aggregates_post_score ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'INSERT') THEN
|
||||
-- Need to get the post creator, not the voter
|
||||
UPDATE
|
||||
person_aggregates ua
|
||||
SET
|
||||
post_score = post_score + NEW.score
|
||||
FROM
|
||||
post p
|
||||
WHERE
|
||||
ua.person_id = p.creator_id
|
||||
AND p.id = NEW.post_id;
|
||||
ELSIF (TG_OP = 'DELETE') THEN
|
||||
UPDATE
|
||||
person_aggregates ua
|
||||
SET
|
||||
post_score = post_score - OLD.score
|
||||
FROM
|
||||
post p
|
||||
WHERE
|
||||
ua.person_id = p.creator_id
|
||||
AND p.id = OLD.post_id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION post_aggregates_comment_count ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
-- Check for post existence - it may not exist anymore
|
||||
IF TG_OP = 'INSERT' OR EXISTS (
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
post p
|
||||
WHERE
|
||||
p.id = OLD.post_id) THEN
|
||||
IF (was_restored_or_created (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
post_aggregates pa
|
||||
SET
|
||||
comments = comments + 1
|
||||
WHERE
|
||||
pa.post_id = NEW.post_id;
|
||||
ELSIF (was_removed_or_deleted (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
post_aggregates pa
|
||||
SET
|
||||
comments = comments - 1
|
||||
WHERE
|
||||
pa.post_id = OLD.post_id;
|
||||
END IF;
|
||||
END IF;
|
||||
IF TG_OP = 'INSERT' THEN
|
||||
UPDATE
|
||||
post_aggregates pa
|
||||
SET
|
||||
newest_comment_time = NEW.published
|
||||
WHERE
|
||||
pa.post_id = NEW.post_id;
|
||||
-- A 2 day necro-bump limit
|
||||
UPDATE
|
||||
post_aggregates pa
|
||||
SET
|
||||
newest_comment_time_necro = NEW.published
|
||||
FROM
|
||||
post p
|
||||
WHERE
|
||||
pa.post_id = p.id
|
||||
AND pa.post_id = NEW.post_id
|
||||
-- Fix issue with being able to necro-bump your own post
|
||||
AND NEW.creator_id != p.creator_id
|
||||
AND pa.published > ('now'::timestamp - '2 days'::interval);
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION post_aggregates_featured_community ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE
|
||||
post_aggregates pa
|
||||
SET
|
||||
featured_community = NEW.featured_community
|
||||
WHERE
|
||||
pa.post_id = NEW.id;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION post_aggregates_featured_local ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE
|
||||
post_aggregates pa
|
||||
SET
|
||||
featured_local = NEW.featured_local
|
||||
WHERE
|
||||
pa.post_id = NEW.id;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION post_aggregates_post ()
|
||||
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)
|
||||
SELECT
|
||||
id,
|
||||
published,
|
||||
published,
|
||||
published,
|
||||
community_id,
|
||||
creator_id,
|
||||
(
|
||||
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
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'INSERT') THEN
|
||||
UPDATE
|
||||
post_aggregates pa
|
||||
SET
|
||||
score = score + NEW.score,
|
||||
upvotes = CASE WHEN NEW.score = 1 THEN
|
||||
upvotes + 1
|
||||
ELSE
|
||||
upvotes
|
||||
END,
|
||||
downvotes = CASE WHEN NEW.score = - 1 THEN
|
||||
downvotes + 1
|
||||
ELSE
|
||||
downvotes
|
||||
END,
|
||||
controversy_rank = controversy_rank (pa.upvotes + CASE WHEN NEW.score = 1 THEN
|
||||
1
|
||||
ELSE
|
||||
0
|
||||
END::numeric, pa.downvotes + CASE WHEN NEW.score = - 1 THEN
|
||||
1
|
||||
ELSE
|
||||
0
|
||||
END::numeric)
|
||||
WHERE
|
||||
pa.post_id = NEW.post_id;
|
||||
ELSIF (TG_OP = 'DELETE') THEN
|
||||
-- Join to post because that post may not exist anymore
|
||||
UPDATE
|
||||
post_aggregates pa
|
||||
SET
|
||||
score = score - OLD.score,
|
||||
upvotes = CASE WHEN OLD.score = 1 THEN
|
||||
upvotes - 1
|
||||
ELSE
|
||||
upvotes
|
||||
END,
|
||||
downvotes = CASE WHEN OLD.score = - 1 THEN
|
||||
downvotes - 1
|
||||
ELSE
|
||||
downvotes
|
||||
END,
|
||||
controversy_rank = controversy_rank (pa.upvotes + CASE WHEN NEW.score = 1 THEN
|
||||
1
|
||||
ELSE
|
||||
0
|
||||
END::numeric, pa.downvotes + CASE WHEN NEW.score = - 1 THEN
|
||||
1
|
||||
ELSE
|
||||
0
|
||||
END::numeric)
|
||||
FROM
|
||||
post p
|
||||
WHERE
|
||||
pa.post_id = p.id
|
||||
AND pa.post_id = OLD.post_id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION post_removed_resolve_reports ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE
|
||||
post_report
|
||||
SET
|
||||
resolved = TRUE,
|
||||
resolver_id = NEW.mod_person_id,
|
||||
updated = now()
|
||||
WHERE
|
||||
post_report.post_id = NEW.post_id;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION site_aggregates_comment_delete ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (was_removed_or_deleted (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
site_aggregates sa
|
||||
SET
|
||||
comments = comments - 1
|
||||
FROM
|
||||
site s
|
||||
WHERE
|
||||
sa.site_id = s.id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION site_aggregates_comment_insert ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (was_restored_or_created (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
site_aggregates sa
|
||||
SET
|
||||
comments = comments + 1
|
||||
FROM
|
||||
site s
|
||||
WHERE
|
||||
sa.site_id = s.id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION site_aggregates_community_insert ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (was_restored_or_created (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
site_aggregates sa
|
||||
SET
|
||||
communities = communities + 1
|
||||
FROM
|
||||
site s
|
||||
WHERE
|
||||
sa.site_id = s.id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION site_aggregates_person_delete ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
-- Join to site since the creator might not be there anymore
|
||||
UPDATE
|
||||
site_aggregates sa
|
||||
SET
|
||||
users = users - 1
|
||||
FROM
|
||||
site s
|
||||
WHERE
|
||||
sa.site_id = s.id;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION site_aggregates_person_insert ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE
|
||||
site_aggregates
|
||||
SET
|
||||
users = users + 1;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION site_aggregates_post_delete ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (was_removed_or_deleted (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
site_aggregates sa
|
||||
SET
|
||||
posts = posts - 1
|
||||
FROM
|
||||
site s
|
||||
WHERE
|
||||
sa.site_id = s.id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION site_aggregates_post_insert ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE
|
||||
site_aggregates sa
|
||||
SET
|
||||
posts = posts + (
|
||||
SELECT
|
||||
count(*)
|
||||
FROM
|
||||
new_post)
|
||||
FROM
|
||||
site s
|
||||
WHERE
|
||||
sa.site_id = s.id;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION site_aggregates_post_update ()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (was_restored_or_created (TG_OP, OLD, NEW)) THEN
|
||||
UPDATE
|
||||
site_aggregates sa
|
||||
SET
|
||||
posts = posts + 1
|
||||
FROM
|
||||
site s
|
||||
WHERE
|
||||
sa.site_id = s.id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION site_aggregates_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 (TG_OP = 'INSERT') AND NOT EXISTS (
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
site_aggregates
|
||||
LIMIT 1) THEN
|
||||
INSERT INTO site_aggregates (site_id)
|
||||
VALUES (NEW.id);
|
||||
ELSIF (TG_OP = 'DELETE') THEN
|
||||
DELETE FROM site_aggregates
|
||||
WHERE site_id = OLD.id;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION was_removed_or_deleted (tg_op text, old record, new record)
|
||||
RETURNS boolean
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'INSERT') THEN
|
||||
RETURN FALSE;
|
||||
END IF;
|
||||
IF (TG_OP = 'DELETE' AND OLD.deleted = 'f' AND OLD.removed = 'f') THEN
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
RETURN TG_OP = 'UPDATE'
|
||||
AND OLD.deleted = 'f'
|
||||
AND OLD.removed = 'f'
|
||||
AND (NEW.deleted = 't'
|
||||
OR NEW.removed = 't');
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE FUNCTION was_restored_or_created (tg_op text, old record, new record)
|
||||
RETURNS boolean
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'DELETE') THEN
|
||||
RETURN FALSE;
|
||||
END IF;
|
||||
IF (TG_OP = 'INSERT') THEN
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
RETURN TG_OP = 'UPDATE'
|
||||
AND NEW.deleted = 'f'
|
||||
AND NEW.removed = 'f'
|
||||
AND (OLD.deleted = 't'
|
||||
OR OLD.removed = 't');
|
||||
END
|
||||
$$;
|
||||
|
||||
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_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_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_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 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_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_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 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_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_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 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_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_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_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 ();
|
||||
|
3
migrations/2023-12-25-034523_replaceable-schema/up.sql
Normal file
3
migrations/2023-12-25-034523_replaceable-schema/up.sql
Normal file
@ -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;
|
||||
|
581
replaceable_schema.sql
Normal file
581
replaceable_schema.sql
Normal file
@ -0,0 +1,581 @@
|
||||
-- This sets up the `r` schema, which contains things that can be safely dropped and replaced instead of being
|
||||
-- changed using migrations.
|
||||
--
|
||||
-- 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):
|
||||
-- * A trigger if the function name after `EXECUTE FUNCTION` is in `r` (dropping `r` drops the trigger)
|
||||
--
|
||||
-- The default schema is not temporarily set to `r` because it would not affect some things (such as triggers) which
|
||||
-- makes it hard to tell if the rule above is being followed.
|
||||
--
|
||||
-- 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;
|
||||
|
||||
CREATE SCHEMA r;
|
||||
|
||||
-- Rank calculations
|
||||
CREATE FUNCTION r.controversy_rank (upvotes numeric, downvotes numeric)
|
||||
RETURNS float
|
||||
LANGUAGE plpgsql
|
||||
IMMUTABLE PARALLEL SAFE
|
||||
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;
|
||||
$$;
|
||||
|
||||
-- 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 ()
|
||||
RETURNS SETOF record
|
||||
LANGUAGE sql
|
||||
AS $$
|
||||
SELECT
|
||||
-1 AS count_diff,
|
||||
*
|
||||
FROM
|
||||
old_table
|
||||
UNION ALL
|
||||
SELECT
|
||||
1 AS count_diff,
|
||||
*
|
||||
FROM
|
||||
new_table;
|
||||
$$;
|
||||
|
||||
-- Define functions
|
||||
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 FUNCTION r.post_not_removed
|
||||
-- Create triggers for both post and comments
|
||||
CREATE PROCEDURE r.post_or_comment (thing_type text)
|
||||
LANGUAGE plpgsql
|
||||
AS $a$
|
||||
BEGIN
|
||||
EXECUTE replace($b$
|
||||
-- When a thing is removed, resolve its reports
|
||||
CREATE FUNCTION r.resolve_reports_when_thing_removed ( )
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE
|
||||
thing_report
|
||||
SET
|
||||
resolved = TRUE, resolver_id = mod_person_id, updated = now()
|
||||
FROM ( SELECT DISTINCT
|
||||
thing_id
|
||||
FROM new_removal
|
||||
WHERE
|
||||
new_removal.removed) AS distinct_removal
|
||||
WHERE
|
||||
report.thing_id = distinct_removal.thing_id
|
||||
AND NOT report.resolved
|
||||
AND COALESCE(report.updated < now(), TRUE);
|
||||
RETURN NULL;
|
||||
END $$;
|
||||
CREATE TRIGGER resolve_reports
|
||||
AFTER INSERT ON mod_remove_thing REFERENCING NEW TABLE AS new_removal
|
||||
FOR EACH STATEMENT
|
||||
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$,
|
||||
'thing',
|
||||
thing_type);
|
||||
END
|
||||
$a$;
|
||||
|
||||
CALL r.post_or_comment ('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 ()
|
||||
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.
|
||||
-- Deleting rows and updating IDs are already handled by `CASCADE` in foreign key constraints.
|
||||
CREATE FUNCTION r.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
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
INSERT INTO community_aggregates (community_id, published)
|
||||
SELECT
|
||||
community_id,
|
||||
published
|
||||
FROM
|
||||
new_community;
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE TRIGGER aggregates
|
||||
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
|
||||
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 ();
|
||||
|
||||
CREATE FUNCTION r.post_aggregates_from_post ()
|
||||
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
|
||||
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,
|
||||
LATERAL (
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
community
|
||||
WHERE
|
||||
community.id = new_post.community_id
|
||||
LIMIT 1) AS community,
|
||||
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 ();
|
||||
|
||||
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
|
||||
INSERT INTO site_aggregates (site_id)
|
||||
VALUES (NEW.id);
|
||||
RETURN NULL;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE TRIGGER aggregates
|
||||
AFTER INSERT ON site
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION r.site_aggregates_from_site ();
|
||||
|
||||
COMMIT;
|
||||
|
16
scripts/dump_schema.sh
Normal file
16
scripts/dump_schema.sh
Normal file
@ -0,0 +1,16 @@
|
||||
#!/usr/bin/env bash
|
||||
set -e
|
||||
|
||||
# Dumps database schema, not including things added by replaceable_schema.sql
|
||||
|
||||
source CWD="$(cd -P -- "$(dirname -- "${BASH_SOURCE[0]}")" && pwd -P)"
|
||||
|
||||
cd $CWD/../
|
||||
|
||||
source scripts/start_dev_db.sh
|
||||
|
||||
diesel migration run
|
||||
pg_dump --no-owner --no-privileges --no-table-access-method --schema-only --no-sync -f schema.sqldump
|
||||
|
||||
pg_ctl stop
|
||||
rm -rf $PGDATA
|
@ -16,3 +16,8 @@ find $TMP_DIR -type f -name '*.sql' -exec pg_format -i {} +
|
||||
|
||||
# Diff the directories
|
||||
diff -r migrations $TMP_DIR
|
||||
|
||||
# Check formatting of replaceable_schema.sql
|
||||
cp -a replaceable_schema.sql $TMP_DIR
|
||||
pg_format -i $TMP_DIR/replaceable_schema.sql
|
||||
diff -r replaceable_schema.sql $TMP_DIR/replaceable_schema.sql
|
||||
|
@ -2,7 +2,10 @@
|
||||
|
||||
export PGDATA="$PWD/dev_pgdata"
|
||||
export PGHOST=$PWD
|
||||
export LEMMY_DATABASE_URL="postgresql://lemmy:password@/lemmy?host=$PWD"
|
||||
export PGUSER=postgres
|
||||
export DATABASE_URL="postgresql://lemmy:password@/lemmy?host=$PWD"
|
||||
export LEMMY_DATABASE_URL=$DATABASE_URL
|
||||
export PGDATABASE=lemmy
|
||||
|
||||
# If cluster exists, stop the server and delete the cluster
|
||||
if [ -d $PGDATA ]
|
||||
@ -20,5 +23,5 @@ initdb --username=postgres --auth=trust --no-instructions
|
||||
pg_ctl start --options="-c listen_addresses= -c unix_socket_directories=$PWD" > /dev/null
|
||||
|
||||
# Setup database
|
||||
psql -c "CREATE USER lemmy WITH PASSWORD 'password' SUPERUSER;" -U postgres
|
||||
psql -c "CREATE DATABASE lemmy WITH OWNER lemmy;" -U postgres
|
||||
PGDATABASE=postgres psql -c "CREATE USER lemmy WITH PASSWORD 'password' SUPERUSER;"
|
||||
PGDATABASE=postgres psql -c "CREATE DATABASE lemmy WITH OWNER lemmy;"
|
||||
|
Loading…
Reference in New Issue
Block a user