From: Sander Saarend Date: Thu, 20 Jul 2023 15:13:21 +0000 (+0300) Subject: Denormalize community_id into post_aggregates for a 1000x speed-up when loading posts... X-Git-Url: http://these/git/%7Bthis.props.siteRes.site_view.site.icon?a=commitdiff_plain;h=b511c2e6cb27b432accddc4e9aa2ec3a4bb7861b;p=lemmy.git Denormalize community_id into post_aggregates for a 1000x speed-up when loading posts (#3653) * 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 --- diff --git a/crates/db_schema/src/aggregates/structs.rs b/crates/db_schema/src/aggregates/structs.rs index 592c63ab..1af94a80 100644 --- a/crates/db_schema/src/aggregates/structs.rs +++ b/crates/db_schema/src/aggregates/structs.rs @@ -96,6 +96,8 @@ pub struct PostAggregates { pub featured_local: bool, pub hot_rank: i32, pub hot_rank_active: i32, + pub community_id: CommunityId, + pub creator_id: PersonId, } #[derive(PartialEq, Eq, Debug, Serialize, Deserialize, Clone)] diff --git a/crates/db_schema/src/schema.rs b/crates/db_schema/src/schema.rs index ae75c31d..17a0f99f 100644 --- a/crates/db_schema/src/schema.rs +++ b/crates/db_schema/src/schema.rs @@ -672,6 +672,8 @@ diesel::table! { featured_local -> Bool, hot_rank -> Int4, hot_rank_active -> Int4, + community_id -> Int4, + creator_id -> Int4, } } @@ -908,6 +910,8 @@ diesel::joinable!(person_post_aggregates -> post (post_id)); diesel::joinable!(post -> community (community_id)); diesel::joinable!(post -> language (language_id)); diesel::joinable!(post -> person (creator_id)); +diesel::joinable!(post_aggregates -> community (community_id)); +diesel::joinable!(post_aggregates -> person (creator_id)); diesel::joinable!(post_aggregates -> post (post_id)); diesel::joinable!(post_like -> person (person_id)); diesel::joinable!(post_like -> post (post_id)); diff --git a/crates/db_views/src/post_report_view.rs b/crates/db_views/src/post_report_view.rs index 50b35b1c..a53762e2 100644 --- a/crates/db_views/src/post_report_view.rs +++ b/crates/db_views/src/post_report_view.rs @@ -470,6 +470,8 @@ mod tests { featured_local: false, hot_rank: 1728, hot_rank_active: 1728, + community_id: inserted_post.community_id, + creator_id: inserted_post.creator_id, }, resolver: None, }; diff --git a/crates/db_views/src/post_view.rs b/crates/db_views/src/post_view.rs index 1d85df3c..d2f6ab75 100644 --- a/crates/db_views/src/post_view.rs +++ b/crates/db_views/src/post_view.rs @@ -72,56 +72,56 @@ impl PostView { // The left join below will return None in this case let person_id_join = my_person_id.unwrap_or(PersonId(-1)); - let mut query = post::table - .find(post_id) + let mut query = post_aggregates::table + .filter(post_aggregates::post_id.eq(post_id)) .inner_join(person::table) .inner_join(community::table) .left_join( community_person_ban::table.on( - post::community_id + post_aggregates::community_id .eq(community_person_ban::community_id) - .and(community_person_ban::person_id.eq(post::creator_id)), + .and(community_person_ban::person_id.eq(post_aggregates::creator_id)), ), ) - .inner_join(post_aggregates::table) + .inner_join(post::table) .left_join( community_follower::table.on( - post::community_id + post_aggregates::community_id .eq(community_follower::community_id) .and(community_follower::person_id.eq(person_id_join)), ), ) .left_join( post_saved::table.on( - post::id + post_aggregates::post_id .eq(post_saved::post_id) .and(post_saved::person_id.eq(person_id_join)), ), ) .left_join( post_read::table.on( - post::id + post_aggregates::post_id .eq(post_read::post_id) .and(post_read::person_id.eq(person_id_join)), ), ) .left_join( person_block::table.on( - post::creator_id + post_aggregates::creator_id .eq(person_block::target_id) .and(person_block::person_id.eq(person_id_join)), ), ) .left_join( post_like::table.on( - post::id + post_aggregates::post_id .eq(post_like::post_id) .and(post_like::person_id.eq(person_id_join)), ), ) .left_join( person_post_aggregates::table.on( - post::id + post_aggregates::post_id .eq(person_post_aggregates::post_id) .and(person_post_aggregates::person_id.eq(person_id_join)), ), @@ -226,62 +226,62 @@ impl<'a> PostQuery<'a> { .map(|l| l.local_user.id) .unwrap_or(LocalUserId(-1)); - let mut query = post::table + let mut query = post_aggregates::table .inner_join(person::table) + .inner_join(post::table) .inner_join(community::table) .left_join( community_person_ban::table.on( - post::community_id + post_aggregates::community_id .eq(community_person_ban::community_id) - .and(community_person_ban::person_id.eq(post::creator_id)), + .and(community_person_ban::person_id.eq(post_aggregates::creator_id)), ), ) - .inner_join(post_aggregates::table) .left_join( community_follower::table.on( - post::community_id + post_aggregates::community_id .eq(community_follower::community_id) .and(community_follower::person_id.eq(person_id_join)), ), ) .left_join( post_saved::table.on( - post::id + post_aggregates::post_id .eq(post_saved::post_id) .and(post_saved::person_id.eq(person_id_join)), ), ) .left_join( post_read::table.on( - post::id + post_aggregates::post_id .eq(post_read::post_id) .and(post_read::person_id.eq(person_id_join)), ), ) .left_join( person_block::table.on( - post::creator_id + post_aggregates::creator_id .eq(person_block::target_id) .and(person_block::person_id.eq(person_id_join)), ), ) .left_join( community_block::table.on( - post::community_id + post_aggregates::community_id .eq(community_block::community_id) .and(community_block::person_id.eq(person_id_join)), ), ) .left_join( post_like::table.on( - post::id + post_aggregates::post_id .eq(post_like::post_id) .and(post_like::person_id.eq(person_id_join)), ), ) .left_join( person_post_aggregates::table.on( - post::id + post_aggregates::post_id .eq(person_post_aggregates::post_id) .and(person_post_aggregates::person_id.eq(person_id_join)), ), @@ -332,12 +332,12 @@ impl<'a> PostQuery<'a> { query = query.then_order_by(post_aggregates::featured_local.desc()); } else if let Some(community_id) = self.community_id { query = query - .filter(post::community_id.eq(community_id)) + .filter(post_aggregates::community_id.eq(community_id)) .then_order_by(post_aggregates::featured_community.desc()); } if let Some(creator_id) = self.creator_id { - query = query.filter(post::creator_id.eq(creator_id)); + query = query.filter(post_aggregates::creator_id.eq(creator_id)); } if let Some(listing_type) = self.listing_type { @@ -1141,6 +1141,8 @@ mod tests { featured_local: false, hot_rank: 1728, hot_rank_active: 1728, + community_id: inserted_post.community_id, + creator_id: inserted_post.creator_id, }, subscribed: SubscribedType::NotSubscribed, read: false, diff --git a/migrations/2023-07-18-082614_post_aggregates_community_id/down.sql b/migrations/2023-07-18-082614_post_aggregates_community_id/down.sql new file mode 100644 index 00000000..91e2dc86 --- /dev/null +++ b/migrations/2023-07-18-082614_post_aggregates_community_id/down.sql @@ -0,0 +1,20 @@ +-- This file should undo anything in `up.sql` + +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) + VALUES (NEW.id, NEW.published, NEW.published, NEW.published); + ELSIF (TG_OP = 'DELETE') THEN + DELETE FROM post_aggregates WHERE post_id = OLD.id; + END IF; + RETURN NULL; +END +$$; + +ALTER TABLE post_aggregates DROP COLUMN community_id, DROP COLUMN creator_id; + diff --git a/migrations/2023-07-18-082614_post_aggregates_community_id/up.sql b/migrations/2023-07-18-082614_post_aggregates_community_id/up.sql new file mode 100644 index 00000000..f28701da --- /dev/null +++ b/migrations/2023-07-18-082614_post_aggregates_community_id/up.sql @@ -0,0 +1,35 @@ +-- 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; \ No newline at end of file