]> Untitled Git - lemmy.git/commitdiff
Adding stickied to post_aggregates.
authorDessalines <tyhou13@gmx.com>
Thu, 7 Jan 2021 21:22:17 +0000 (16:22 -0500)
committerDessalines <tyhou13@gmx.com>
Thu, 7 Jan 2021 21:22:17 +0000 (16:22 -0500)
- Added more indexes to account for sorting by stickied first.
- Changed all order bys in the diesel views to use post_aggregates.

lemmy_db_queries/src/aggregates/post_aggregates.rs
lemmy_db_schema/src/schema.rs
lemmy_db_views/src/post_view.rs
migrations/2020-12-10-152350_create_post_aggregates/down.sql
migrations/2020-12-10-152350_create_post_aggregates/up.sql
migrations/2021-01-05-200932_add_hot_rank_indexes/down.sql
migrations/2021-01-05-200932_add_hot_rank_indexes/up.sql
query_testing/views_to_diesel_migration/generate_reports.sh
query_testing/views_to_diesel_migration/timings-1.out [deleted file]

index 6c1dbed27f8c342440cdd49df6f836583c28fd1d..d5f78bf15ce0e587574fc1d70751ab2ad3d6bdd7 100644 (file)
@@ -11,6 +11,7 @@ pub struct PostAggregates {
   pub score: i64,
   pub upvotes: i64,
   pub downvotes: i64,
+  pub stickied: bool,
   pub published: chrono::NaiveDateTime,
   pub newest_comment_time: chrono::NaiveDateTime,
 }
index fa5d8c21d9b69060b160af95cafc06fcae00716d..bbc2e7b80ea9471fcef71b01b58f0b9127e2335c 100644 (file)
@@ -282,6 +282,7 @@ table! {
         score -> Int8,
         upvotes -> Int8,
         downvotes -> Int8,
+        stickied -> Bool,
         published -> Timestamp,
         newest_comment_time -> Timestamp,
     }
index 7b88cfcab93094e0b1bd6f84edf5a9f6ca91087d..2f82f8fe04fac9642ca8d8f63af3076aa46f19a4 100644 (file)
@@ -302,14 +302,14 @@ impl<'a> PostQueryBuilder<'a> {
     if let Some(community_id) = self.community_id {
       query = query
         .filter(post::community_id.eq(community_id))
-        .then_order_by(post::stickied.desc());
+        .then_order_by(post_aggregates::stickied.desc());
     }
 
     if let Some(community_name) = self.community_name {
       query = query
         .filter(community::name.eq(community_name))
         .filter(community::local.eq(true))
-        .then_order_by(post::stickied.desc());
+        .then_order_by(post_aggregates::stickied.desc());
     }
 
     if let Some(url_search) = self.url_search {
@@ -354,7 +354,7 @@ impl<'a> PostQueryBuilder<'a> {
       SortType::Hot => query
         .then_order_by(hot_rank(post_aggregates::score, post_aggregates::published).desc())
         .then_order_by(post_aggregates::published.desc()),
-      SortType::New => query.then_order_by(post::published.desc()),
+      SortType::New => query.then_order_by(post_aggregates::published.desc()),
       SortType::TopAll => query.then_order_by(post_aggregates::score.desc()),
       SortType::TopYear => query
         .filter(post::published.gt(now - 1.years()))
@@ -605,6 +605,7 @@ mod tests {
         score: 1,
         upvotes: 1,
         downvotes: 0,
+        stickied: false,
         published: agg.published,
         newest_comment_time: inserted_post.published,
       },
index 113f26d04f2edec878a13dc304070dedbc0f1cdf..7b4024cdac757ba002051dcb3286e5cdb0c716e2 100644 (file)
@@ -3,7 +3,9 @@ drop table post_aggregates;
 drop trigger post_aggregates_post on post;
 drop trigger post_aggregates_comment_count on comment;
 drop trigger post_aggregates_score on post_like;
+drop trigger post_aggregates_stickied on post;
 drop function 
   post_aggregates_post,
   post_aggregates_comment_count,
-  post_aggregates_score;
+  post_aggregates_score,
+  post_aggregates_stickied;
index 784f33e20c4149f8db3223aac008e4d159426005..aaa611c4e9c5c8e17f21938d70d1b95821f16c3e 100644 (file)
@@ -6,18 +6,20 @@ create table post_aggregates (
   score bigint not null default 0,
   upvotes bigint not null default 0,
   downvotes bigint not null default 0,
+  stickied boolean not null default false,
   published timestamp not null default now(),
   newest_comment_time timestamp not null default now(),
   unique (post_id)
 );
 
-insert into post_aggregates (post_id, comments, score, upvotes, downvotes, published, newest_comment_time)
+insert into post_aggregates (post_id, comments, score, upvotes, downvotes, stickied, published, newest_comment_time)
   select 
     p.id,
     coalesce(ct.comments, 0::bigint) as comments,
     coalesce(pl.score, 0::bigint) as score,
     coalesce(pl.upvotes, 0::bigint) as upvotes,
     coalesce(pl.downvotes, 0::bigint) as downvotes,
+    p.stickied,
     p.published,
     greatest(ct.recent_comment_time, p.published) as newest_activity_time
   from post p
@@ -115,3 +117,21 @@ create trigger post_aggregates_score
 after insert or delete on post_like
 for each row
 execute procedure post_aggregates_score();
+
+-- post stickied
+create function post_aggregates_stickied()
+returns trigger language plpgsql
+as $$
+begin
+  update post_aggregates pa
+  set stickied = NEW.stickied
+  where pa.post_id = NEW.id;
+
+  return null;
+end $$;
+
+create trigger post_aggregates_stickied
+after update on post
+for each row
+when (OLD.stickied is distinct from NEW.stickied)
+execute procedure post_aggregates_stickied();
index 2ec455a5899ea5d06aeec636d0ff435ce8ac7919..55e833323f088a4cd4e9f54c8967b1acf0143ea7 100644 (file)
@@ -10,11 +10,14 @@ end; $$
 LANGUAGE plpgsql;
 
 drop index 
-  idx_post_published,
-  idx_post_stickied,
   idx_post_aggregates_hot,
+  idx_post_aggregates_stickied_hot,
   idx_post_aggregates_active,
+  idx_post_aggregates_stickied_active,
   idx_post_aggregates_score,
+  idx_post_aggregates_stickied_score,
+  idx_post_aggregates_published,
+  idx_post_aggregates_stickied_published,
   idx_comment_published,
   idx_comment_aggregates_hot,
   idx_comment_aggregates_score,
index a6c452340ccd1d049560c14a3ecb7140cb1057bd..f4d4147106429b4e938f500abc7951182daa9a2e 100644 (file)
@@ -12,15 +12,19 @@ end; $$
 LANGUAGE plpgsql
 IMMUTABLE;
 
--- Post
-create index idx_post_published on post (published desc);
-create index idx_post_stickied on post (stickied desc);
-
 -- Post_aggregates
+create index idx_post_aggregates_stickied_hot on post_aggregates (stickied desc, hot_rank(score, published) desc, published desc);
 create index idx_post_aggregates_hot on post_aggregates (hot_rank(score, published) desc, published desc);
+
+create index idx_post_aggregates_stickied_active on post_aggregates (stickied desc, hot_rank(score, newest_comment_time) desc, newest_comment_time desc);
 create index idx_post_aggregates_active on post_aggregates (hot_rank(score, newest_comment_time) desc, newest_comment_time desc);
+
+create index idx_post_aggregates_stickied_score on post_aggregates (stickied desc, score desc);
 create index idx_post_aggregates_score on post_aggregates (score desc);
 
+create index idx_post_aggregates_stickied_published on post_aggregates (stickied desc, published desc);
+create index idx_post_aggregates_published on post_aggregates (published desc);
+
 -- Comment
 create index idx_comment_published on comment (published desc);
 
index fe4880cde1a6da22fddbd5fd7883ae3a94f62a3b..12993a0800e306645ce8ea1fc331b1840e5e68bf 100755 (executable)
@@ -16,8 +16,20 @@ cat explain.sql | $PSQL_CMD > post.json
 echo "explain (analyze, format json) select * from post p, post_aggregates pa where p.id = pa.post_id order by hot_rank(pa.score, pa.published) desc, pa.published desc limit 100" > explain.sql
 cat explain.sql | $PSQL_CMD > post_ordered_by_rank.json
 
-echo "explain (analyze, format json) select * from post p, post_aggregates pa where p.id = pa.post_id order by p.stickied desc, hot_rank(pa.score, pa.published) desc, pa.published desc limit 100" > explain.sql
-cat explain.sql | $PSQL_CMD > post_ordered_by_stickied.json
+echo "explain (analyze, format json) select * from post p, post_aggregates pa where p.id = pa.post_id order by pa.stickied desc, hot_rank(pa.score, pa.published) desc, pa.published desc limit 100" > explain.sql
+cat explain.sql | $PSQL_CMD > post_ordered_by_stickied_then_rank.json
+
+echo "explain (analyze, format json) select * from post p, post_aggregates pa where p.id = pa.post_id order by pa.score desc limit 100" > explain.sql
+cat explain.sql | $PSQL_CMD > post_ordered_by_score.json
+
+echo "explain (analyze, format json) select * from post p, post_aggregates pa where p.id = pa.post_id order by pa.stickied desc, pa.score desc limit 100" > explain.sql
+cat explain.sql | $PSQL_CMD > post_ordered_by_stickied_then_score.json
+
+echo "explain (analyze, format json) select * from post p, post_aggregates pa where p.id = pa.post_id order by pa.published desc limit 100" > explain.sql
+cat explain.sql | $PSQL_CMD > post_ordered_by_published.json
+
+echo "explain (analyze, format json) select * from post p, post_aggregates pa where p.id = pa.post_id order by pa.stickied desc, pa.published desc limit 100" > explain.sql
+cat explain.sql | $PSQL_CMD > post_ordered_by_stickied_then_published.json
 
 echo "explain (analyze, format json) select * from comment limit 100" > explain.sql
 cat explain.sql | $PSQL_CMD > comment.json
diff --git a/query_testing/views_to_diesel_migration/timings-1.out b/query_testing/views_to_diesel_migration/timings-1.out
deleted file mode 100644 (file)
index 2df7743..0000000
+++ /dev/null
@@ -1,9 +0,0 @@
-comment.json:    "Execution Time": 12.263
-community.json:    "Execution Time": 1.225
-community_ordered_by_subscribers.json:    "Execution Time": 170.255
-post.json:    "Execution Time": 5.373
-post_ordered_by_rank.json:    "Execution Time": 1458.801
-private_message.json:    "Execution Time": 0.306
-site.json:    "Execution Time": 0.064
-user_.json:    "Execution Time": 2.606
-user_mention.json:    "Execution Time": 0.135