Some more DB optimizings

- Changing the fast_id pkeys to just ids on the fast tables.
- Removing the private_message_fast, since the view contains no aggregates.
- Comment and post voting now no longer pull from the views, they update the counts directly.
This commit is contained in:
Dessalines 2020-07-06 10:10:11 -04:00
parent 768328ae83
commit 6cb66dc941
8 changed files with 71 additions and 157 deletions

View file

@ -4,7 +4,6 @@ drop view post_fast_view;
drop table post_aggregates_fast;
drop view community_fast_view;
drop table community_aggregates_fast;
drop table private_message_fast;
drop view reply_fast_view;
drop view user_mention_fast_view;
drop view comment_fast_view;
@ -27,8 +26,6 @@ begin
return null;
end $$;
drop trigger refresh_private_message on private_message;
create trigger refresh_private_message
after insert or update or delete or truncate
on private_message

View file

@ -1,5 +1,3 @@
-- Drop the mviews
drop view post_mview;
drop materialized view user_mview;
@ -11,12 +9,11 @@ drop view comment_mview;
drop materialized view post_aggregates_mview;
drop materialized view community_aggregates_mview;
drop materialized view comment_aggregates_mview;
drop trigger refresh_private_message on private_message;
-- User
create table user_fast as select * from user_view;
alter table user_fast add column fast_id serial primary key;
create index idx_user_fast_id on user_fast (id);
alter table user_fast add primary key (id);
drop trigger refresh_user on user_;
@ -59,9 +56,7 @@ end $$;
-- Post
create table post_aggregates_fast as select * from post_aggregates_view;
alter table post_aggregates_fast add column fast_id serial primary key;
create index idx_post_aggregates_fast_id on post_aggregates_fast (id);
alter table post_aggregates_fast add primary key (id);
-- For the hot rank resorting
create index idx_post_aggregates_fast_hot_rank_published on post_aggregates_fast (hot_rank desc, published desc);
@ -145,9 +140,7 @@ end $$;
-- Community
create table community_aggregates_fast as select * from community_aggregates_view;
alter table community_aggregates_fast add column fast_id serial primary key;
create index idx_community_aggregates_fast_id on community_aggregates_fast (id);
alter table community_aggregates_fast add primary key (id);
create view community_fast_view as
select
@ -211,49 +204,10 @@ begin
return null;
end $$;
-- Private message
create table private_message_fast as select * from private_message_view;
alter table private_message_fast add column fast_id serial primary key;
create index idx_private_message_fast_id on private_message_fast (id);
drop trigger refresh_private_message on private_message;
create trigger refresh_private_message
after insert or update or delete
on private_message
for each row
execute procedure refresh_private_message();
-- Sample insert
-- insert into private_message(creator_id, recipient_id, content) values (2, 3, 'test_private_message');
-- Sample delete
-- delete from private_message where content like 'test_private_message';
-- Sample update
-- update private_message set ap_id = 'test' where content like 'test_private_message';
create or replace function refresh_private_message()
returns trigger language plpgsql
as $$
begin
IF (TG_OP = 'DELETE') THEN
delete from private_message_fast where id = OLD.id;
ELSIF (TG_OP = 'UPDATE') THEN
delete from private_message_fast where id = OLD.id;
insert into private_message_fast select * from private_message_view where id = NEW.id;
ELSIF (TG_OP = 'INSERT') THEN
insert into private_message_fast select * from private_message_view where id = NEW.id;
END IF;
return null;
end $$;
-- Comment
create table comment_aggregates_fast as select * from comment_aggregates_view;
alter table comment_aggregates_fast add column fast_id serial primary key;
create index idx_comment_aggregates_fast_id on comment_aggregates_fast (id);
alter table comment_aggregates_fast add primary key (id);
create view comment_fast_view as
select
@ -465,14 +419,30 @@ returns trigger language plpgsql
as $$
begin
IF (TG_OP = 'DELETE') THEN
delete from post_aggregates_fast where id = OLD.post_id;
insert into post_aggregates_fast select * from post_aggregates_view where id = OLD.post_id;
ELSIF (TG_OP = 'UPDATE') THEN
delete from post_aggregates_fast where id = NEW.post_id;
insert into post_aggregates_fast select * from post_aggregates_view where id = NEW.post_id;
update post_aggregates_fast
set score = case
when (OLD.score = 1) then score - 1
else score + 1 end,
upvotes = case
when (OLD.score = 1) then upvotes - 1
else upvotes end,
downvotes = case
when (OLD.score = -1) then downvotes - 1
else downvotes end
where id = OLD.post_id;
ELSIF (TG_OP = 'INSERT') THEN
delete from post_aggregates_fast where id = NEW.post_id;
insert into post_aggregates_fast select * from post_aggregates_view where id = NEW.post_id;
update post_aggregates_fast
set score = case
when (NEW.score = 1) then score + 1
else score - 1 end,
upvotes = case
when (NEW.score = 1) then upvotes + 1
else upvotes end,
downvotes = case
when (NEW.score = -1) then downvotes + 1
else downvotes end
where id = NEW.post_id;
END IF;
return null;
@ -480,7 +450,7 @@ end $$;
drop trigger refresh_post_like on post_like;
create trigger refresh_post_like
after insert or update or delete
after insert or delete
on post_like
for each row
execute procedure refresh_post_like();
@ -499,14 +469,30 @@ as $$
begin
-- TODO possibly select from comment_fast to get previous scores, instead of re-fetching the views?
IF (TG_OP = 'DELETE') THEN
delete from comment_aggregates_fast where id = OLD.comment_id;
insert into comment_aggregates_fast select * from comment_aggregates_view where id = OLD.comment_id;
ELSIF (TG_OP = 'UPDATE') THEN
delete from comment_aggregates_fast where id = NEW.comment_id;
insert into comment_aggregates_fast select * from comment_aggregates_view where id = NEW.comment_id;
update comment_aggregates_fast
set score = case
when (OLD.score = 1) then score - 1
else score + 1 end,
upvotes = case
when (OLD.score = 1) then upvotes - 1
else upvotes end,
downvotes = case
when (OLD.score = -1) then downvotes - 1
else downvotes end
where id = OLD.comment_id;
ELSIF (TG_OP = 'INSERT') THEN
delete from comment_aggregates_fast where id = NEW.comment_id;
insert into comment_aggregates_fast select * from comment_aggregates_view where id = NEW.comment_id;
update comment_aggregates_fast
set score = case
when (NEW.score = 1) then score + 1
else score - 1 end,
upvotes = case
when (NEW.score = 1) then upvotes + 1
else upvotes end,
downvotes = case
when (NEW.score = -1) then downvotes + 1
else downvotes end
where id = NEW.comment_id;
END IF;
return null;
@ -514,7 +500,7 @@ end $$;
drop trigger refresh_comment_like on comment_like;
create trigger refresh_comment_like
after insert or update or delete
after insert or delete
on comment_like
for each row
execute procedure refresh_comment_like();
@ -523,7 +509,7 @@ execute procedure refresh_comment_like();
drop trigger refresh_community_user_ban on community_user_ban;
create trigger refresh_community_user_ban
after insert or update or delete
after insert or delete -- Note this is missing after update
on community_user_ban
for each row
execute procedure refresh_community_user_ban();
@ -557,7 +543,7 @@ end $$;
drop trigger refresh_community_follower on community_follower;
create trigger refresh_community_follower
after insert or update or delete
after insert or delete -- Note this is missing after update
on community_follower
for each row
execute procedure refresh_community_follower();

View file

@ -1,3 +1,4 @@
// TODO, remove the cross join here, just join to user directly
use crate::db::{fuzzy_search, limit_and_offset, ListingType, MaybeOptional, SortType};
use diesel::{dsl::*, pg::Pg, result::Error, *};
use serde::{Deserialize, Serialize};
@ -66,7 +67,6 @@ table! {
upvotes -> BigInt,
downvotes -> BigInt,
hot_rank -> Int4,
fast_id -> Int4,
user_id -> Nullable<Int4>,
my_vote -> Nullable<Int4>,
subscribed -> Nullable<Bool>,
@ -105,7 +105,6 @@ pub struct CommentView {
pub upvotes: i64,
pub downvotes: i64,
pub hot_rank: i32,
pub fast_id: i32,
pub user_id: Option<i32>,
pub my_vote: Option<i32>,
pub subscribed: Option<bool>,
@ -319,7 +318,6 @@ table! {
upvotes -> BigInt,
downvotes -> BigInt,
hot_rank -> Int4,
fast_id -> Int4,
user_id -> Nullable<Int4>,
my_vote -> Nullable<Int4>,
subscribed -> Nullable<Bool>,
@ -359,7 +357,6 @@ pub struct ReplyView {
pub upvotes: i64,
pub downvotes: i64,
pub hot_rank: i32,
pub fast_id: i32,
pub user_id: Option<i32>,
pub my_vote: Option<i32>,
pub subscribed: Option<bool>,
@ -583,7 +580,6 @@ mod tests {
score: 1,
downvotes: 0,
hot_rank: 0,
fast_id: 0,
upvotes: 1,
user_id: None,
my_vote: None,
@ -617,7 +613,6 @@ mod tests {
score: 1,
downvotes: 0,
hot_rank: 0,
fast_id: 0,
upvotes: 1,
user_id: Some(inserted_user.id),
my_vote: Some(1),
@ -636,7 +631,6 @@ mod tests {
.list()
.unwrap();
read_comment_views_no_user[0].hot_rank = 0;
read_comment_views_no_user[0].fast_id = 0;
let mut read_comment_views_with_user = CommentQueryBuilder::create(&conn)
.for_post_id(inserted_post.id)
@ -644,7 +638,6 @@ mod tests {
.list()
.unwrap();
read_comment_views_with_user[0].hot_rank = 0;
read_comment_views_with_user[0].fast_id = 0;
let like_removed = CommentLike::remove(&conn, &comment_like_form).unwrap();
let num_deleted = Comment::delete(&conn, inserted_comment.id).unwrap();

View file

@ -58,7 +58,6 @@ table! {
number_of_posts -> BigInt,
number_of_comments -> BigInt,
hot_rank -> Int4,
fast_id -> Int4,
user_id -> Nullable<Int4>,
subscribed -> Nullable<Bool>,
}
@ -140,7 +139,6 @@ pub struct CommunityView {
pub number_of_posts: i64,
pub number_of_comments: i64,
pub hot_rank: i32,
pub fast_id: i32,
pub user_id: Option<i32>,
pub subscribed: Option<bool>,
}

View file

@ -90,7 +90,6 @@ table! {
downvotes -> BigInt,
hot_rank -> Int4,
newest_activity_time -> Timestamp,
fast_id -> Int4,
user_id -> Nullable<Int4>,
my_vote -> Nullable<Int4>,
subscribed -> Nullable<Bool>,
@ -141,7 +140,6 @@ pub struct PostView {
pub downvotes: i64,
pub hot_rank: i32,
pub newest_activity_time: chrono::NaiveDateTime,
pub fast_id: i32,
pub user_id: Option<i32>,
pub my_vote: Option<i32>,
pub subscribed: Option<bool>,
@ -520,7 +518,6 @@ mod tests {
hot_rank: read_post_listing_no_user.hot_rank,
published: inserted_post.published,
newest_activity_time: inserted_post.published,
fast_id: read_post_listing_no_user.fast_id,
updated: None,
subscribed: None,
read: None,
@ -566,7 +563,6 @@ mod tests {
hot_rank: read_post_listing_with_user.hot_rank,
published: inserted_post.published,
newest_activity_time: inserted_post.published,
fast_id: read_post_listing_with_user.fast_id,
updated: None,
subscribed: None,
read: None,

View file

@ -26,34 +26,10 @@ table! {
}
}
table! {
private_message_fast (id) {
id -> Int4,
creator_id -> Int4,
recipient_id -> Int4,
content -> Text,
deleted -> Bool,
read -> Bool,
published -> Timestamp,
updated -> Nullable<Timestamp>,
ap_id -> Text,
local -> Bool,
creator_name -> Varchar,
creator_avatar -> Nullable<Text>,
creator_actor_id -> Text,
creator_local -> Bool,
recipient_name -> Varchar,
recipient_avatar -> Nullable<Text>,
recipient_actor_id -> Text,
recipient_local -> Bool,
fast_id -> Int4,
}
}
#[derive(
Queryable, Identifiable, PartialEq, Debug, Serialize, Deserialize, QueryableByName, Clone,
)]
#[table_name = "private_message_fast"]
#[table_name = "private_message_view"]
pub struct PrivateMessageView {
pub id: i32,
pub creator_id: i32,
@ -73,12 +49,11 @@ pub struct PrivateMessageView {
pub recipient_avatar: Option<String>,
pub recipient_actor_id: String,
pub recipient_local: bool,
pub fast_id: i32,
}
pub struct PrivateMessageQueryBuilder<'a> {
conn: &'a PgConnection,
query: super::private_message_view::private_message_fast::BoxedQuery<'a, Pg>,
query: super::private_message_view::private_message_view::BoxedQuery<'a, Pg>,
for_recipient_id: i32,
unread_only: bool,
page: Option<i64>,
@ -87,9 +62,9 @@ pub struct PrivateMessageQueryBuilder<'a> {
impl<'a> PrivateMessageQueryBuilder<'a> {
pub fn create(conn: &'a PgConnection, for_recipient_id: i32) -> Self {
use super::private_message_view::private_message_fast::dsl::*;
use super::private_message_view::private_message_view::dsl::*;
let query = private_message_fast.into_boxed();
let query = private_message_view.into_boxed();
PrivateMessageQueryBuilder {
conn,
@ -117,7 +92,7 @@ impl<'a> PrivateMessageQueryBuilder<'a> {
}
pub fn list(self) -> Result<Vec<PrivateMessageView>, Error> {
use super::private_message_view::private_message_fast::dsl::*;
use super::private_message_view::private_message_view::dsl::*;
let mut query = self.query.filter(deleted.eq(false));
@ -148,9 +123,9 @@ impl<'a> PrivateMessageQueryBuilder<'a> {
impl PrivateMessageView {
pub fn read(conn: &PgConnection, from_private_message_id: i32) -> Result<Self, Error> {
use super::private_message_view::private_message_fast::dsl::*;
use super::private_message_view::private_message_view::dsl::*;
let mut query = private_message_fast.into_boxed();
let mut query = private_message_view.into_boxed();
query = query
.filter(id.eq(from_private_message_id))

View file

@ -44,7 +44,6 @@ table! {
post_score -> BigInt,
number_of_comments -> BigInt,
comment_score -> BigInt,
fast_id -> Int4,
}
}
@ -70,7 +69,6 @@ pub struct UserView {
pub post_score: i64,
pub number_of_comments: i64,
pub comment_score: i64,
pub fast_id: i32,
}
pub struct UserQueryBuilder<'a> {

View file

@ -34,8 +34,8 @@ table! {
}
table! {
comment_aggregates_fast (fast_id) {
id -> Nullable<Int4>,
comment_aggregates_fast (id) {
id -> Int4,
creator_id -> Nullable<Int4>,
post_id -> Nullable<Int4>,
parent_id -> Nullable<Int4>,
@ -61,7 +61,6 @@ table! {
upvotes -> Nullable<Int8>,
downvotes -> Nullable<Int8>,
hot_rank -> Nullable<Int4>,
fast_id -> Int4,
}
}
@ -107,8 +106,8 @@ table! {
}
table! {
community_aggregates_fast (fast_id) {
id -> Nullable<Int4>,
community_aggregates_fast (id) {
id -> Int4,
name -> Nullable<Varchar>,
title -> Nullable<Varchar>,
description -> Nullable<Text>,
@ -131,7 +130,6 @@ table! {
number_of_posts -> Nullable<Int8>,
number_of_comments -> Nullable<Int8>,
hot_rank -> Nullable<Int4>,
fast_id -> Int4,
}
}
@ -296,8 +294,8 @@ table! {
}
table! {
post_aggregates_fast (fast_id) {
id -> Nullable<Int4>,
post_aggregates_fast (id) {
id -> Int4,
name -> Nullable<Varchar>,
url -> Nullable<Text>,
body -> Nullable<Text>,
@ -334,7 +332,6 @@ table! {
downvotes -> Nullable<Int8>,
hot_rank -> Nullable<Int4>,
newest_activity_time -> Nullable<Timestamp>,
fast_id -> Int4,
}
}
@ -381,30 +378,6 @@ table! {
}
}
table! {
private_message_fast (fast_id) {
id -> Nullable<Int4>,
creator_id -> Nullable<Int4>,
recipient_id -> Nullable<Int4>,
content -> Nullable<Text>,
deleted -> Nullable<Bool>,
read -> Nullable<Bool>,
published -> Nullable<Timestamp>,
updated -> Nullable<Timestamp>,
ap_id -> Nullable<Varchar>,
local -> Nullable<Bool>,
creator_name -> Nullable<Varchar>,
creator_avatar -> Nullable<Text>,
creator_actor_id -> Nullable<Varchar>,
creator_local -> Nullable<Bool>,
recipient_name -> Nullable<Varchar>,
recipient_avatar -> Nullable<Text>,
recipient_actor_id -> Nullable<Varchar>,
recipient_local -> Nullable<Bool>,
fast_id -> Int4,
}
}
table! {
site (id) {
id -> Int4,
@ -457,8 +430,8 @@ table! {
}
table! {
user_fast (fast_id) {
id -> Nullable<Int4>,
user_fast (id) {
id -> Int4,
actor_id -> Nullable<Varchar>,
name -> Nullable<Varchar>,
avatar -> Nullable<Text>,
@ -475,7 +448,6 @@ table! {
post_score -> Nullable<Int8>,
number_of_comments -> Nullable<Int8>,
comment_score -> Nullable<Int8>,
fast_id -> Int4,
}
}
@ -559,7 +531,6 @@ allow_tables_to_appear_in_same_query!(
post_read,
post_saved,
private_message,
private_message_fast,
site,
user_,
user_ban,