Adding stickied to post_aggregates.
- Added more indexes to account for sorting by stickied first. - Changed all order bys in the diesel views to use post_aggregates.
This commit is contained in:
parent
b9b51c2dfc
commit
7a97fc370b
9 changed files with 57 additions and 22 deletions
|
@ -11,6 +11,7 @@ pub struct PostAggregates {
|
||||||
pub score: i64,
|
pub score: i64,
|
||||||
pub upvotes: i64,
|
pub upvotes: i64,
|
||||||
pub downvotes: i64,
|
pub downvotes: i64,
|
||||||
|
pub stickied: bool,
|
||||||
pub published: chrono::NaiveDateTime,
|
pub published: chrono::NaiveDateTime,
|
||||||
pub newest_comment_time: chrono::NaiveDateTime,
|
pub newest_comment_time: chrono::NaiveDateTime,
|
||||||
}
|
}
|
||||||
|
|
|
@ -282,6 +282,7 @@ table! {
|
||||||
score -> Int8,
|
score -> Int8,
|
||||||
upvotes -> Int8,
|
upvotes -> Int8,
|
||||||
downvotes -> Int8,
|
downvotes -> Int8,
|
||||||
|
stickied -> Bool,
|
||||||
published -> Timestamp,
|
published -> Timestamp,
|
||||||
newest_comment_time -> Timestamp,
|
newest_comment_time -> Timestamp,
|
||||||
}
|
}
|
||||||
|
|
|
@ -302,14 +302,14 @@ impl<'a> PostQueryBuilder<'a> {
|
||||||
if let Some(community_id) = self.community_id {
|
if let Some(community_id) = self.community_id {
|
||||||
query = query
|
query = query
|
||||||
.filter(post::community_id.eq(community_id))
|
.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 {
|
if let Some(community_name) = self.community_name {
|
||||||
query = query
|
query = query
|
||||||
.filter(community::name.eq(community_name))
|
.filter(community::name.eq(community_name))
|
||||||
.filter(community::local.eq(true))
|
.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 {
|
if let Some(url_search) = self.url_search {
|
||||||
|
@ -354,7 +354,7 @@ impl<'a> PostQueryBuilder<'a> {
|
||||||
SortType::Hot => query
|
SortType::Hot => query
|
||||||
.then_order_by(hot_rank(post_aggregates::score, post_aggregates::published).desc())
|
.then_order_by(hot_rank(post_aggregates::score, post_aggregates::published).desc())
|
||||||
.then_order_by(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::TopAll => query.then_order_by(post_aggregates::score.desc()),
|
||||||
SortType::TopYear => query
|
SortType::TopYear => query
|
||||||
.filter(post::published.gt(now - 1.years()))
|
.filter(post::published.gt(now - 1.years()))
|
||||||
|
@ -605,6 +605,7 @@ mod tests {
|
||||||
score: 1,
|
score: 1,
|
||||||
upvotes: 1,
|
upvotes: 1,
|
||||||
downvotes: 0,
|
downvotes: 0,
|
||||||
|
stickied: false,
|
||||||
published: agg.published,
|
published: agg.published,
|
||||||
newest_comment_time: inserted_post.published,
|
newest_comment_time: inserted_post.published,
|
||||||
},
|
},
|
||||||
|
|
|
@ -3,7 +3,9 @@ drop table post_aggregates;
|
||||||
drop trigger post_aggregates_post on post;
|
drop trigger post_aggregates_post on post;
|
||||||
drop trigger post_aggregates_comment_count on comment;
|
drop trigger post_aggregates_comment_count on comment;
|
||||||
drop trigger post_aggregates_score on post_like;
|
drop trigger post_aggregates_score on post_like;
|
||||||
|
drop trigger post_aggregates_stickied on post;
|
||||||
drop function
|
drop function
|
||||||
post_aggregates_post,
|
post_aggregates_post,
|
||||||
post_aggregates_comment_count,
|
post_aggregates_comment_count,
|
||||||
post_aggregates_score;
|
post_aggregates_score,
|
||||||
|
post_aggregates_stickied;
|
||||||
|
|
|
@ -6,18 +6,20 @@ create table post_aggregates (
|
||||||
score bigint not null default 0,
|
score bigint not null default 0,
|
||||||
upvotes bigint not null default 0,
|
upvotes bigint not null default 0,
|
||||||
downvotes bigint not null default 0,
|
downvotes bigint not null default 0,
|
||||||
|
stickied boolean not null default false,
|
||||||
published timestamp not null default now(),
|
published timestamp not null default now(),
|
||||||
newest_comment_time timestamp not null default now(),
|
newest_comment_time timestamp not null default now(),
|
||||||
unique (post_id)
|
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
|
select
|
||||||
p.id,
|
p.id,
|
||||||
coalesce(ct.comments, 0::bigint) as comments,
|
coalesce(ct.comments, 0::bigint) as comments,
|
||||||
coalesce(pl.score, 0::bigint) as score,
|
coalesce(pl.score, 0::bigint) as score,
|
||||||
coalesce(pl.upvotes, 0::bigint) as upvotes,
|
coalesce(pl.upvotes, 0::bigint) as upvotes,
|
||||||
coalesce(pl.downvotes, 0::bigint) as downvotes,
|
coalesce(pl.downvotes, 0::bigint) as downvotes,
|
||||||
|
p.stickied,
|
||||||
p.published,
|
p.published,
|
||||||
greatest(ct.recent_comment_time, p.published) as newest_activity_time
|
greatest(ct.recent_comment_time, p.published) as newest_activity_time
|
||||||
from post p
|
from post p
|
||||||
|
@ -115,3 +117,21 @@ create trigger post_aggregates_score
|
||||||
after insert or delete on post_like
|
after insert or delete on post_like
|
||||||
for each row
|
for each row
|
||||||
execute procedure post_aggregates_score();
|
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();
|
||||||
|
|
|
@ -10,11 +10,14 @@ end; $$
|
||||||
LANGUAGE plpgsql;
|
LANGUAGE plpgsql;
|
||||||
|
|
||||||
drop index
|
drop index
|
||||||
idx_post_published,
|
|
||||||
idx_post_stickied,
|
|
||||||
idx_post_aggregates_hot,
|
idx_post_aggregates_hot,
|
||||||
|
idx_post_aggregates_stickied_hot,
|
||||||
idx_post_aggregates_active,
|
idx_post_aggregates_active,
|
||||||
|
idx_post_aggregates_stickied_active,
|
||||||
idx_post_aggregates_score,
|
idx_post_aggregates_score,
|
||||||
|
idx_post_aggregates_stickied_score,
|
||||||
|
idx_post_aggregates_published,
|
||||||
|
idx_post_aggregates_stickied_published,
|
||||||
idx_comment_published,
|
idx_comment_published,
|
||||||
idx_comment_aggregates_hot,
|
idx_comment_aggregates_hot,
|
||||||
idx_comment_aggregates_score,
|
idx_comment_aggregates_score,
|
||||||
|
|
|
@ -12,15 +12,19 @@ end; $$
|
||||||
LANGUAGE plpgsql
|
LANGUAGE plpgsql
|
||||||
IMMUTABLE;
|
IMMUTABLE;
|
||||||
|
|
||||||
-- Post
|
|
||||||
create index idx_post_published on post (published desc);
|
|
||||||
create index idx_post_stickied on post (stickied desc);
|
|
||||||
|
|
||||||
-- Post_aggregates
|
-- 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_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_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_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
|
-- Comment
|
||||||
create index idx_comment_published on comment (published desc);
|
create index idx_comment_published on comment (published desc);
|
||||||
|
|
||||||
|
|
|
@ -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
|
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
|
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
|
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.json
|
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
|
echo "explain (analyze, format json) select * from comment limit 100" > explain.sql
|
||||||
cat explain.sql | $PSQL_CMD > comment.json
|
cat explain.sql | $PSQL_CMD > comment.json
|
||||||
|
|
|
@ -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
|
|
Loading…
Reference in a new issue