mirror of
https://github.com/LemmyNet/lemmy.git
synced 2024-11-30 08:11:20 +00:00
b511c2e6cb
* Denormalize community_id into post_aggregates for a 1000x speed-up when loading posts * Remove unused index * Add creator_id to post_aggregates * Use post_aggregates as main table for PostQuery * Make post_aggregates the main table for PostView * Reformat SQL
35 lines
No EOL
1.1 KiB
PL/PgSQL
35 lines
No EOL
1.1 KiB
PL/PgSQL
-- Your SQL goes here
|
|
ALTER TABLE post_aggregates
|
|
ADD COLUMN community_id integer REFERENCES community ON UPDATE CASCADE ON DELETE CASCADE,
|
|
ADD COLUMN creator_id integer REFERENCES person ON UPDATE CASCADE ON DELETE CASCADE;
|
|
|
|
CREATE OR REPLACE FUNCTION post_aggregates_post()
|
|
RETURNS trigger
|
|
LANGUAGE plpgsql
|
|
AS
|
|
$$
|
|
BEGIN
|
|
IF (TG_OP = 'INSERT') THEN
|
|
INSERT INTO post_aggregates (post_id,
|
|
published,
|
|
newest_comment_time,
|
|
newest_comment_time_necro,
|
|
community_id,
|
|
creator_id)
|
|
VALUES (NEW.id, NEW.published, NEW.published, NEW.published, NEW.community_id, NEW.creator_id);
|
|
ELSIF (TG_OP = 'DELETE') THEN
|
|
DELETE FROM post_aggregates WHERE post_id = OLD.id;
|
|
END IF;
|
|
RETURN NULL;
|
|
END
|
|
$$;
|
|
|
|
UPDATE post_aggregates
|
|
SET community_id=post.community_id,
|
|
creator_id=post.creator_id
|
|
FROM post
|
|
WHERE post.id = post_aggregates.post_id;
|
|
|
|
ALTER TABLE post_aggregates
|
|
ALTER COLUMN community_id SET NOT NULL,
|
|
ALTER COLUMN creator_id SET NOT NULL; |