From 8f32b84b5ab44e4b72b0ff7e7f4515a0a4835185 Mon Sep 17 00:00:00 2001 From: Dessalines Date: Mon, 13 Jan 2020 20:02:02 -0500 Subject: [PATCH] A first pass at using materialized views. --- server/.gitignore | 1 + .../down.sql | 223 +++++++++ .../up.sql | 437 ++++++++++++++++++ .../down.sql | 211 +++++++++ .../up.sql | 324 +++++++++++++ server/query_testing/apache_bench_report.sh | 1 + .../query_testing/generate_explain_reports.sh | 11 +- server/src/db/comment_view.rs | 34 +- server/src/db/community_view.rs | 33 +- server/src/db/post_view.rs | 51 +- server/src/db/user_view.rs | 37 +- server/src/routes/websocket.rs | 2 +- 12 files changed, 1333 insertions(+), 32 deletions(-) create mode 100644 server/migrations/2020-01-13-025151_create_materialized_views/down.sql create mode 100644 server/migrations/2020-01-13-025151_create_materialized_views/up.sql create mode 100644 server/migrations_testing/2020-01-13-025151_create_materialized_views/down.sql create mode 100644 server/migrations_testing/2020-01-13-025151_create_materialized_views/up.sql diff --git a/server/.gitignore b/server/.gitignore index f2a595fd7..00e9d4525 100644 --- a/server/.gitignore +++ b/server/.gitignore @@ -3,3 +3,4 @@ .idea env_setup.sh query_testing/*.json +query_testing/*.json.old diff --git a/server/migrations/2020-01-13-025151_create_materialized_views/down.sql b/server/migrations/2020-01-13-025151_create_materialized_views/down.sql new file mode 100644 index 000000000..39985ab55 --- /dev/null +++ b/server/migrations/2020-01-13-025151_create_materialized_views/down.sql @@ -0,0 +1,223 @@ +-- functions and triggers +drop trigger refresh_user on user_; +drop function refresh_user(); +drop trigger refresh_post on post; +drop function refresh_post(); +drop trigger refresh_post_like on post_like; +drop function refresh_post_like(); +drop trigger refresh_community on community; +drop function refresh_community(); +drop trigger refresh_community_follower on community_follower; +drop function refresh_community_follower(); +drop trigger refresh_community_user_ban on community_user_ban; +drop function refresh_community_user_ban(); +drop trigger refresh_comment on comment; +drop function refresh_comment(); +drop trigger refresh_comment_like on comment_like; +drop function refresh_comment_like(); + +-- post +-- Recreate the view +drop view post_view; +create view post_view as +with all_post as +( + select + p.*, + (select u.banned from user_ u where p.creator_id = u.id) as banned, + (select cb.id::bool from community_user_ban cb where p.creator_id = cb.user_id and p.community_id = cb.community_id) as banned_from_community, + (select name from user_ where p.creator_id = user_.id) as creator_name, + (select avatar from user_ where p.creator_id = user_.id) as creator_avatar, + (select name from community where p.community_id = community.id) as community_name, + (select removed from community c where p.community_id = c.id) as community_removed, + (select deleted from community c where p.community_id = c.id) as community_deleted, + (select nsfw from community c where p.community_id = c.id) as community_nsfw, + (select count(*) from comment where comment.post_id = p.id) as number_of_comments, + coalesce(sum(pl.score), 0) as score, + count (case when pl.score = 1 then 1 else null end) as upvotes, + count (case when pl.score = -1 then 1 else null end) as downvotes, + hot_rank(coalesce(sum(pl.score) , 0), p.published) as hot_rank + from post p + left join post_like pl on p.id = pl.post_id + group by p.id +) + +select +ap.*, +u.id as user_id, +coalesce(pl.score, 0) as my_vote, +(select cf.id::bool from community_follower cf where u.id = cf.user_id and cf.community_id = ap.community_id) as subscribed, +(select pr.id::bool from post_read pr where u.id = pr.user_id and pr.post_id = ap.id) as read, +(select ps.id::bool from post_saved ps where u.id = ps.user_id and ps.post_id = ap.id) as saved +from user_ u +cross join all_post ap +left join post_like pl on u.id = pl.user_id and ap.id = pl.post_id + +union all + +select +ap.*, +null as user_id, +null as my_vote, +null as subscribed, +null as read, +null as saved +from all_post ap +; + +drop view post_mview; +drop materialized view post_aggregates_mview; +drop view post_aggregates_view; + +-- user +drop materialized view user_mview; +drop view user_view; +create view user_view as +select id, +name, +avatar, +email, +fedi_name, +admin, +banned, +show_avatars, +send_notifications_to_email, +published, +(select count(*) from post p where p.creator_id = u.id) as number_of_posts, +(select coalesce(sum(score), 0) from post p, post_like pl where u.id = p.creator_id and p.id = pl.post_id) as post_score, +(select count(*) from comment c where c.creator_id = u.id) as number_of_comments, +(select coalesce(sum(score), 0) from comment c, comment_like cl where u.id = c.creator_id and c.id = cl.comment_id) as comment_score +from user_ u; + +-- community +drop view community_mview; +drop materialized view community_aggregates_mview; +drop view community_view; +drop view community_aggregates_view; +create view community_view as +with all_community as +( + select *, + (select name from user_ u where c.creator_id = u.id) as creator_name, + (select avatar from user_ u where c.creator_id = u.id) as creator_avatar, + (select name from category ct where c.category_id = ct.id) as category_name, + (select count(*) from community_follower cf where cf.community_id = c.id) as number_of_subscribers, + (select count(*) from post p where p.community_id = c.id) as number_of_posts, + (select count(*) from comment co, post p where c.id = p.community_id and p.id = co.post_id) as number_of_comments, + hot_rank((select count(*) from community_follower cf where cf.community_id = c.id), c.published) as hot_rank + from community c +) + +select +ac.*, +u.id as user_id, +(select cf.id::boolean from community_follower cf where u.id = cf.user_id and ac.id = cf.community_id) as subscribed +from user_ u +cross join all_community ac + +union all + +select +ac.*, +null as user_id, +null as subscribed +from all_community ac +; + +-- reply and comment view +drop view reply_view; +drop view user_mention_view; +drop view comment_view; +drop view comment_mview; +drop materialized view comment_aggregates_mview; +drop view comment_aggregates_view; +create view comment_view as +with all_comment as +( + select + c.*, + (select community_id from post p where p.id = c.post_id), + (select u.banned from user_ u where c.creator_id = u.id) as banned, + (select cb.id::bool from community_user_ban cb, post p where c.creator_id = cb.user_id and p.id = c.post_id and p.community_id = cb.community_id) as banned_from_community, + (select name from user_ where c.creator_id = user_.id) as creator_name, + (select avatar from user_ where c.creator_id = user_.id) as creator_avatar, + coalesce(sum(cl.score), 0) as score, + count (case when cl.score = 1 then 1 else null end) as upvotes, + count (case when cl.score = -1 then 1 else null end) as downvotes + from comment c + left join comment_like cl on c.id = cl.comment_id + group by c.id +) + +select +ac.*, +u.id as user_id, +coalesce(cl.score, 0) as my_vote, +(select cs.id::bool from comment_saved cs where u.id = cs.user_id and cs.comment_id = ac.id) as saved +from user_ u +cross join all_comment ac +left join comment_like cl on u.id = cl.user_id and ac.id = cl.comment_id + +union all + +select + ac.*, + null as user_id, + null as my_vote, + null as saved +from all_comment ac +; + +create view reply_view as +with closereply as ( + select + c2.id, + c2.creator_id as sender_id, + c.creator_id as recipient_id + from comment c + inner join comment c2 on c.id = c2.parent_id + where c2.creator_id != c.creator_id + -- Do union where post is null + union + select + c.id, + c.creator_id as sender_id, + p.creator_id as recipient_id + from comment c, post p + where c.post_id = p.id and c.parent_id is null and c.creator_id != p.creator_id +) +select cv.*, +closereply.recipient_id +from comment_view cv, closereply +where closereply.id = cv.id +; + +-- user mention +create view user_mention_view as +select + c.id, + um.id as user_mention_id, + c.creator_id, + c.post_id, + c.parent_id, + c.content, + c.removed, + um.read, + c.published, + c.updated, + c.deleted, + c.community_id, + c.banned, + c.banned_from_community, + c.creator_name, + c.creator_avatar, + c.score, + c.upvotes, + c.downvotes, + c.user_id, + c.my_vote, + c.saved, + um.recipient_id +from user_mention um, comment_view c +where um.comment_id = c.id; + diff --git a/server/migrations/2020-01-13-025151_create_materialized_views/up.sql b/server/migrations/2020-01-13-025151_create_materialized_views/up.sql new file mode 100644 index 000000000..e0f206d34 --- /dev/null +++ b/server/migrations/2020-01-13-025151_create_materialized_views/up.sql @@ -0,0 +1,437 @@ +-- post +create view post_aggregates_view as +select +p.*, +(select u.banned from user_ u where p.creator_id = u.id) as banned, +(select cb.id::bool from community_user_ban cb where p.creator_id = cb.user_id and p.community_id = cb.community_id) as banned_from_community, +(select name from user_ where p.creator_id = user_.id) as creator_name, +(select avatar from user_ where p.creator_id = user_.id) as creator_avatar, +(select name from community where p.community_id = community.id) as community_name, +(select removed from community c where p.community_id = c.id) as community_removed, +(select deleted from community c where p.community_id = c.id) as community_deleted, +(select nsfw from community c where p.community_id = c.id) as community_nsfw, +(select count(*) from comment where comment.post_id = p.id) as number_of_comments, +coalesce(sum(pl.score), 0) as score, +count (case when pl.score = 1 then 1 else null end) as upvotes, +count (case when pl.score = -1 then 1 else null end) as downvotes, +hot_rank(coalesce(sum(pl.score) , 0), p.published) as hot_rank +from post p +left join post_like pl on p.id = pl.post_id +group by p.id; + +create materialized view post_aggregates_mview as select * from post_aggregates_view; + +create unique index idx_post_aggregates_mview_id on post_aggregates_mview (id); + +drop view post_view; +create view post_view as +with all_post as ( + select + pa.* + from post_aggregates_view pa +) +select +ap.*, +u.id as user_id, +coalesce(pl.score, 0) as my_vote, +(select cf.id::bool from community_follower cf where u.id = cf.user_id and cf.community_id = ap.community_id) as subscribed, +(select pr.id::bool from post_read pr where u.id = pr.user_id and pr.post_id = ap.id) as read, +(select ps.id::bool from post_saved ps where u.id = ps.user_id and ps.post_id = ap.id) as saved +from user_ u +cross join all_post ap +left join post_like pl on u.id = pl.user_id and ap.id = pl.post_id + +union all + +select +ap.*, +null as user_id, +null as my_vote, +null as subscribed, +null as read, +null as saved +from all_post ap +; + +create view post_mview as +with all_post as ( + select + pa.* + from post_aggregates_mview pa +) +select +ap.*, +u.id as user_id, +coalesce(pl.score, 0) as my_vote, +(select cf.id::bool from community_follower cf where u.id = cf.user_id and cf.community_id = ap.community_id) as subscribed, +(select pr.id::bool from post_read pr where u.id = pr.user_id and pr.post_id = ap.id) as read, +(select ps.id::bool from post_saved ps where u.id = ps.user_id and ps.post_id = ap.id) as saved +from user_ u +cross join all_post ap +left join post_like pl on u.id = pl.user_id and ap.id = pl.post_id + +union all + +select +ap.*, +null as user_id, +null as my_vote, +null as subscribed, +null as read, +null as saved +from all_post ap +; + + +-- user_view +drop view user_view; +create view user_view as +select +u.id, +u.name, +u.avatar, +u.email, +u.fedi_name, +u.admin, +u.banned, +u.show_avatars, +u.send_notifications_to_email, +u.published, +(select count(*) from post p where p.creator_id = u.id) as number_of_posts, +(select coalesce(sum(score), 0) from post p, post_like pl where u.id = p.creator_id and p.id = pl.post_id) as post_score, +(select count(*) from comment c where c.creator_id = u.id) as number_of_comments, +(select coalesce(sum(score), 0) from comment c, comment_like cl where u.id = c.creator_id and c.id = cl.comment_id) as comment_score +from user_ u; + +create materialized view user_mview as select * from user_view; + +create unique index idx_user_mview_id on user_mview (id); + +-- community +create view community_aggregates_view as +select c.*, +(select name from user_ u where c.creator_id = u.id) as creator_name, +(select avatar from user_ u where c.creator_id = u.id) as creator_avatar, +(select name from category ct where c.category_id = ct.id) as category_name, +(select count(*) from community_follower cf where cf.community_id = c.id) as number_of_subscribers, +(select count(*) from post p where p.community_id = c.id) as number_of_posts, +(select count(*) from comment co, post p where c.id = p.community_id and p.id = co.post_id) as number_of_comments, +hot_rank((select count(*) from community_follower cf where cf.community_id = c.id), c.published) as hot_rank +from community c; + +create materialized view community_aggregates_mview as select * from community_aggregates_view; + +create unique index idx_community_aggregates_mview_id on community_aggregates_mview (id); + +drop view community_view; +create view community_view as +with all_community as +( + select + ca.* + from community_aggregates_view ca +) + +select +ac.*, +u.id as user_id, +(select cf.id::boolean from community_follower cf where u.id = cf.user_id and ac.id = cf.community_id) as subscribed +from user_ u +cross join all_community ac + +union all + +select +ac.*, +null as user_id, +null as subscribed +from all_community ac +; + +create view community_mview as +with all_community as +( + select + ca.* + from community_aggregates_mview ca +) + +select +ac.*, +u.id as user_id, +(select cf.id::boolean from community_follower cf where u.id = cf.user_id and ac.id = cf.community_id) as subscribed +from user_ u +cross join all_community ac + +union all + +select +ac.*, +null as user_id, +null as subscribed +from all_community ac +; + + +-- reply and comment view +create view comment_aggregates_view as +select +c.*, +(select community_id from post p where p.id = c.post_id), +(select u.banned from user_ u where c.creator_id = u.id) as banned, +(select cb.id::bool from community_user_ban cb, post p where c.creator_id = cb.user_id and p.id = c.post_id and p.community_id = cb.community_id) as banned_from_community, +(select name from user_ where c.creator_id = user_.id) as creator_name, +(select avatar from user_ where c.creator_id = user_.id) as creator_avatar, +coalesce(sum(cl.score), 0) as score, +count (case when cl.score = 1 then 1 else null end) as upvotes, +count (case when cl.score = -1 then 1 else null end) as downvotes +from comment c +left join comment_like cl on c.id = cl.comment_id +group by c.id; + +create materialized view comment_aggregates_mview as select * from comment_aggregates_view; + +create unique index idx_comment_aggregates_mview_id on comment_aggregates_mview (id); + +drop view reply_view; +drop view user_mention_view; +drop view comment_view; + +create view comment_view as +with all_comment as +( + select + ca.* + from comment_aggregates_view ca +) + +select +ac.*, +u.id as user_id, +coalesce(cl.score, 0) as my_vote, +(select cs.id::bool from comment_saved cs where u.id = cs.user_id and cs.comment_id = ac.id) as saved +from user_ u +cross join all_comment ac +left join comment_like cl on u.id = cl.user_id and ac.id = cl.comment_id + +union all + +select + ac.*, + null as user_id, + null as my_vote, + null as saved +from all_comment ac +; + +create view comment_mview as +with all_comment as +( + select + ca.* + from comment_aggregates_mview ca +) + +select +ac.*, +u.id as user_id, +coalesce(cl.score, 0) as my_vote, +(select cs.id::bool from comment_saved cs where u.id = cs.user_id and cs.comment_id = ac.id) as saved +from user_ u +cross join all_comment ac +left join comment_like cl on u.id = cl.user_id and ac.id = cl.comment_id + +union all + +select + ac.*, + null as user_id, + null as my_vote, + null as saved +from all_comment ac +; + +create view reply_view as +with closereply as ( + select + c2.id, + c2.creator_id as sender_id, + c.creator_id as recipient_id + from comment c + inner join comment c2 on c.id = c2.parent_id + where c2.creator_id != c.creator_id + -- Do union where post is null + union + select + c.id, + c.creator_id as sender_id, + p.creator_id as recipient_id + from comment c, post p + where c.post_id = p.id and c.parent_id is null and c.creator_id != p.creator_id +) +select cv.*, +closereply.recipient_id +from comment_view cv, closereply +where closereply.id = cv.id +; + +-- user mention +create view user_mention_view as +select + c.id, + um.id as user_mention_id, + c.creator_id, + c.post_id, + c.parent_id, + c.content, + c.removed, + um.read, + c.published, + c.updated, + c.deleted, + c.community_id, + c.banned, + c.banned_from_community, + c.creator_name, + c.creator_avatar, + c.score, + c.upvotes, + c.downvotes, + c.user_id, + c.my_vote, + c.saved, + um.recipient_id +from user_mention um, comment_view c +where um.comment_id = c.id; + +-- user +create or replace function refresh_user() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently user_mview; + refresh materialized view concurrently comment_aggregates_mview; -- cause of bans + refresh materialized view concurrently post_aggregates_mview; + return null; +end $$; + +create trigger refresh_user +after insert or update or delete or truncate +on user_ +for each statement +execute procedure refresh_user(); + +-- post +create or replace function refresh_post() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently post_aggregates_mview; + refresh materialized view concurrently user_mview; + return null; +end $$; + +create trigger refresh_post +after insert or update or delete or truncate +on post +for each statement +execute procedure refresh_post(); + +-- post_like +create or replace function refresh_post_like() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently post_aggregates_mview; + refresh materialized view concurrently user_mview; + return null; +end $$; + +create trigger refresh_post_like +after insert or update or delete or truncate +on post_like +for each statement +execute procedure refresh_post_like(); + +-- community +create or replace function refresh_community() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently post_aggregates_mview; + refresh materialized view concurrently community_aggregates_mview; + refresh materialized view concurrently user_mview; + return null; +end $$; + +create trigger refresh_community +after insert or update or delete or truncate +on community +for each statement +execute procedure refresh_community(); + +-- community_follower +create or replace function refresh_community_follower() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently community_aggregates_mview; + refresh materialized view concurrently post_aggregates_mview; + return null; +end $$; + +create trigger refresh_community_follower +after insert or update or delete or truncate +on community_follower +for each statement +execute procedure refresh_community_follower(); + +-- community_user_ban +create or replace function refresh_community_user_ban() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently comment_aggregates_mview; + refresh materialized view concurrently post_aggregates_mview; + return null; +end $$; + +create trigger refresh_community_user_ban +after insert or update or delete or truncate +on community_user_ban +for each statement +execute procedure refresh_community_user_ban(); + +-- comment +create or replace function refresh_comment() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently post_aggregates_mview; + refresh materialized view concurrently comment_aggregates_mview; + refresh materialized view concurrently community_aggregates_mview; + refresh materialized view concurrently user_mview; + return null; +end $$; + +create trigger refresh_comment +after insert or update or delete or truncate +on comment +for each statement +execute procedure refresh_comment(); + +-- comment_like +create or replace function refresh_comment_like() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently comment_aggregates_mview; + refresh materialized view concurrently user_mview; + return null; +end $$; + +create trigger refresh_comment_like +after insert or update or delete or truncate +on comment_like +for each statement +execute procedure refresh_comment_like(); diff --git a/server/migrations_testing/2020-01-13-025151_create_materialized_views/down.sql b/server/migrations_testing/2020-01-13-025151_create_materialized_views/down.sql new file mode 100644 index 000000000..ba801ba54 --- /dev/null +++ b/server/migrations_testing/2020-01-13-025151_create_materialized_views/down.sql @@ -0,0 +1,211 @@ +-- functions and triggers +drop trigger refresh_user on user_; +drop function refresh_user(); +drop trigger refresh_post on post; +drop function refresh_post(); +drop trigger refresh_post_like on post_like; +drop function refresh_post_like(); +drop trigger refresh_community on community; +drop function refresh_community(); +drop trigger refresh_community_follower on community_follower; +drop function refresh_community_follower(); +drop trigger refresh_comment on comment; +drop function refresh_comment(); +drop trigger refresh_comment_like on comment_like; +drop function refresh_comment_like(); + +-- post +-- Recreate the view +drop materialized view post_view; +create view post_view as +with all_post as +( + select + p.*, + (select u.banned from user_ u where p.creator_id = u.id) as banned, + (select cb.id::bool from community_user_ban cb where p.creator_id = cb.user_id and p.community_id = cb.community_id) as banned_from_community, + (select name from user_ where p.creator_id = user_.id) as creator_name, + (select avatar from user_ where p.creator_id = user_.id) as creator_avatar, + (select name from community where p.community_id = community.id) as community_name, + (select removed from community c where p.community_id = c.id) as community_removed, + (select deleted from community c where p.community_id = c.id) as community_deleted, + (select nsfw from community c where p.community_id = c.id) as community_nsfw, + (select count(*) from comment where comment.post_id = p.id) as number_of_comments, + coalesce(sum(pl.score), 0) as score, + count (case when pl.score = 1 then 1 else null end) as upvotes, + count (case when pl.score = -1 then 1 else null end) as downvotes, + hot_rank(coalesce(sum(pl.score) , 0), p.published) as hot_rank + from post p + left join post_like pl on p.id = pl.post_id + group by p.id +) + +select +ap.*, +u.id as user_id, +coalesce(pl.score, 0) as my_vote, +(select cf.id::bool from community_follower cf where u.id = cf.user_id and cf.community_id = ap.community_id) as subscribed, +(select pr.id::bool from post_read pr where u.id = pr.user_id and pr.post_id = ap.id) as read, +(select ps.id::bool from post_saved ps where u.id = ps.user_id and ps.post_id = ap.id) as saved +from user_ u +cross join all_post ap +left join post_like pl on u.id = pl.user_id and ap.id = pl.post_id + +union all + +select +ap.*, +null as user_id, +null as my_vote, +null as subscribed, +null as read, +null as saved +from all_post ap +; + + +drop materialized view user_view; +create view user_view as +select id, +name, +avatar, +email, +fedi_name, +admin, +banned, +show_avatars, +send_notifications_to_email, +published, +(select count(*) from post p where p.creator_id = u.id) as number_of_posts, +(select coalesce(sum(score), 0) from post p, post_like pl where u.id = p.creator_id and p.id = pl.post_id) as post_score, +(select count(*) from comment c where c.creator_id = u.id) as number_of_comments, +(select coalesce(sum(score), 0) from comment c, comment_like cl where u.id = c.creator_id and c.id = cl.comment_id) as comment_score +from user_ u; + + +-- community +drop materialized view community_view; +create view community_view as +with all_community as +( + select *, + (select name from user_ u where c.creator_id = u.id) as creator_name, + (select avatar from user_ u where c.creator_id = u.id) as creator_avatar, + (select name from category ct where c.category_id = ct.id) as category_name, + (select count(*) from community_follower cf where cf.community_id = c.id) as number_of_subscribers, + (select count(*) from post p where p.community_id = c.id) as number_of_posts, + (select count(*) from comment co, post p where c.id = p.community_id and p.id = co.post_id) as number_of_comments, + hot_rank((select count(*) from community_follower cf where cf.community_id = c.id), c.published) as hot_rank + from community c +) + +select +ac.*, +u.id as user_id, +(select cf.id::boolean from community_follower cf where u.id = cf.user_id and ac.id = cf.community_id) as subscribed +from user_ u +cross join all_community ac + +union all + +select +ac.*, +null as user_id, +null as subscribed +from all_community ac +; + +-- reply and comment view +drop view reply_view; +drop view user_mention_view; +drop materialized view comment_view; +create view comment_view as +with all_comment as +( + select + c.*, + (select community_id from post p where p.id = c.post_id), + (select u.banned from user_ u where c.creator_id = u.id) as banned, + (select cb.id::bool from community_user_ban cb, post p where c.creator_id = cb.user_id and p.id = c.post_id and p.community_id = cb.community_id) as banned_from_community, + (select name from user_ where c.creator_id = user_.id) as creator_name, + (select avatar from user_ where c.creator_id = user_.id) as creator_avatar, + coalesce(sum(cl.score), 0) as score, + count (case when cl.score = 1 then 1 else null end) as upvotes, + count (case when cl.score = -1 then 1 else null end) as downvotes + from comment c + left join comment_like cl on c.id = cl.comment_id + group by c.id +) + +select +ac.*, +u.id as user_id, +coalesce(cl.score, 0) as my_vote, +(select cs.id::bool from comment_saved cs where u.id = cs.user_id and cs.comment_id = ac.id) as saved +from user_ u +cross join all_comment ac +left join comment_like cl on u.id = cl.user_id and ac.id = cl.comment_id + +union all + +select + ac.*, + null as user_id, + null as my_vote, + null as saved +from all_comment ac +; + +create view reply_view as +with closereply as ( + select + c2.id, + c2.creator_id as sender_id, + c.creator_id as recipient_id + from comment c + inner join comment c2 on c.id = c2.parent_id + where c2.creator_id != c.creator_id + -- Do union where post is null + union + select + c.id, + c.creator_id as sender_id, + p.creator_id as recipient_id + from comment c, post p + where c.post_id = p.id and c.parent_id is null and c.creator_id != p.creator_id +) +select cv.*, +closereply.recipient_id +from comment_view cv, closereply +where closereply.id = cv.id +; + +-- user mention +create view user_mention_view as +select + c.id, + um.id as user_mention_id, + c.creator_id, + c.post_id, + c.parent_id, + c.content, + c.removed, + um.read, + c.published, + c.updated, + c.deleted, + c.community_id, + c.banned, + c.banned_from_community, + c.creator_name, + c.creator_avatar, + c.score, + c.upvotes, + c.downvotes, + c.user_id, + c.my_vote, + c.saved, + um.recipient_id +from user_mention um, comment_view c +where um.comment_id = c.id; + diff --git a/server/migrations_testing/2020-01-13-025151_create_materialized_views/up.sql b/server/migrations_testing/2020-01-13-025151_create_materialized_views/up.sql new file mode 100644 index 000000000..33b0442f1 --- /dev/null +++ b/server/migrations_testing/2020-01-13-025151_create_materialized_views/up.sql @@ -0,0 +1,324 @@ +-- post +drop view post_view; +create materialized view post_view as +with all_post as +( + select + p.*, + (select u.banned from user_ u where p.creator_id = u.id) as banned, + (select cb.id::bool from community_user_ban cb where p.creator_id = cb.user_id and p.community_id = cb.community_id) as banned_from_community, + (select name from user_ where p.creator_id = user_.id) as creator_name, + (select avatar from user_ where p.creator_id = user_.id) as creator_avatar, + (select name from community where p.community_id = community.id) as community_name, + (select removed from community c where p.community_id = c.id) as community_removed, + (select deleted from community c where p.community_id = c.id) as community_deleted, + (select nsfw from community c where p.community_id = c.id) as community_nsfw, + (select count(*) from comment where comment.post_id = p.id) as number_of_comments, + coalesce(sum(pl.score), 0) as score, + count (case when pl.score = 1 then 1 else null end) as upvotes, + count (case when pl.score = -1 then 1 else null end) as downvotes, + hot_rank(coalesce(sum(pl.score) , 0), p.published) as hot_rank + from post p + left join post_like pl on p.id = pl.post_id + group by p.id +) + +select +ap.*, +u.id as user_id, +coalesce(pl.score, 0) as my_vote, +(select cf.id::bool from community_follower cf where u.id = cf.user_id and cf.community_id = ap.community_id) as subscribed, +(select pr.id::bool from post_read pr where u.id = pr.user_id and pr.post_id = ap.id) as read, +(select ps.id::bool from post_saved ps where u.id = ps.user_id and ps.post_id = ap.id) as saved +from user_ u +cross join all_post ap +left join post_like pl on u.id = pl.user_id and ap.id = pl.post_id + +union all + +select +ap.*, +null as user_id, +null as my_vote, +null as subscribed, +null as read, +null as saved +from all_post ap +with data +; + +create unique index idx_post_view_unique on post_view (id, user_id); +create index idx_post_view_user_id on post_view (user_id); +create index idx_post_view_hot_rank_published on post_view (hot_rank desc, published desc); +create index idx_post_view_published on post_view (published desc); +create index idx_post_view_score on post_view (score desc); + +-- user_view +drop view user_view; +create materialized view user_view as +select id, +name, +avatar, +email, +fedi_name, +admin, +banned, +show_avatars, +send_notifications_to_email, +published, +(select count(*) from post p where p.creator_id = u.id) as number_of_posts, +(select coalesce(sum(score), 0) from post p, post_like pl where u.id = p.creator_id and p.id = pl.post_id) as post_score, +(select count(*) from comment c where c.creator_id = u.id) as number_of_comments, +(select coalesce(sum(score), 0) from comment c, comment_like cl where u.id = c.creator_id and c.id = cl.comment_id) as comment_score +from user_ u; + +create unique index idx_user_view_unique on user_view (id); +create index idx_user_view_comment_published on user_view (comment_score desc, published desc); +create index idx_user_view_admin on user_view (admin); +create index idx_user_view_banned on user_view (banned); + +-- community +drop view community_view; +create materialized view community_view as +with all_community as +( + select *, + (select name from user_ u where c.creator_id = u.id) as creator_name, + (select avatar from user_ u where c.creator_id = u.id) as creator_avatar, + (select name from category ct where c.category_id = ct.id) as category_name, + (select count(*) from community_follower cf where cf.community_id = c.id) as number_of_subscribers, + (select count(*) from post p where p.community_id = c.id) as number_of_posts, + (select count(*) from comment co, post p where c.id = p.community_id and p.id = co.post_id) as number_of_comments, + hot_rank((select count(*) from community_follower cf where cf.community_id = c.id), c.published) as hot_rank + from community c +) + +select +ac.*, +u.id as user_id, +(select cf.id::boolean from community_follower cf where u.id = cf.user_id and ac.id = cf.community_id) as subscribed +from user_ u +cross join all_community ac + +union all + +select +ac.*, +null as user_id, +null as subscribed +from all_community ac +; + +create unique index idx_community_view_unique on community_view (id, user_id); +create index idx_community_view_user_id on community_view (user_id); +create index idx_community_view_hot_rank_subscribed on community_view (hot_rank desc, number_of_subscribers desc); + + +-- reply and comment view +drop view reply_view; +drop view user_mention_view; +drop view comment_view; +create materialized view comment_view as +with all_comment as +( + select + c.*, + (select community_id from post p where p.id = c.post_id), + (select u.banned from user_ u where c.creator_id = u.id) as banned, + (select cb.id::bool from community_user_ban cb, post p where c.creator_id = cb.user_id and p.id = c.post_id and p.community_id = cb.community_id) as banned_from_community, + (select name from user_ where c.creator_id = user_.id) as creator_name, + (select avatar from user_ where c.creator_id = user_.id) as creator_avatar, + coalesce(sum(cl.score), 0) as score, + count (case when cl.score = 1 then 1 else null end) as upvotes, + count (case when cl.score = -1 then 1 else null end) as downvotes + from comment c + left join comment_like cl on c.id = cl.comment_id + group by c.id +) + +select +ac.*, +u.id as user_id, +coalesce(cl.score, 0) as my_vote, +(select cs.id::bool from comment_saved cs where u.id = cs.user_id and cs.comment_id = ac.id) as saved +from user_ u +cross join all_comment ac +left join comment_like cl on u.id = cl.user_id and ac.id = cl.comment_id + +union all + +select + ac.*, + null as user_id, + null as my_vote, + null as saved +from all_comment ac +; + +create unique index idx_comment_view_unique on comment_view (id, user_id); +create index idx_comment_view_user_id on comment_view (user_id); +create index idx_comment_view_creator_id on comment_view (creator_id); +create index idx_comment_view_post_id on comment_view (post_id); +create index idx_comment_view_score on comment_view (score desc); + +create view reply_view as +with closereply as ( + select + c2.id, + c2.creator_id as sender_id, + c.creator_id as recipient_id + from comment c + inner join comment c2 on c.id = c2.parent_id + where c2.creator_id != c.creator_id + -- Do union where post is null + union + select + c.id, + c.creator_id as sender_id, + p.creator_id as recipient_id + from comment c, post p + where c.post_id = p.id and c.parent_id is null and c.creator_id != p.creator_id +) +select cv.*, +closereply.recipient_id +from comment_view cv, closereply +where closereply.id = cv.id +; + +-- user mention +create view user_mention_view as +select + c.id, + um.id as user_mention_id, + c.creator_id, + c.post_id, + c.parent_id, + c.content, + c.removed, + um.read, + c.published, + c.updated, + c.deleted, + c.community_id, + c.banned, + c.banned_from_community, + c.creator_name, + c.creator_avatar, + c.score, + c.upvotes, + c.downvotes, + c.user_id, + c.my_vote, + c.saved, + um.recipient_id +from user_mention um, comment_view c +where um.comment_id = c.id; + +-- user +create or replace function refresh_user() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently comment_view; -- cause of bans + refresh materialized view concurrently post_view; + return null; +end $$; + +create trigger refresh_user +after insert or update or delete or truncate +on user_ +for each statement +execute procedure refresh_user(); + +-- post +create or replace function refresh_post() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently post_view; + return null; +end $$; + +create trigger refresh_post +after insert or update or delete or truncate +on post +for each statement +execute procedure refresh_post(); + +-- post_like +create or replace function refresh_post_like() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently post_view; + return null; +end $$; + +create trigger refresh_post_like +after insert or update or delete or truncate +on post_like +for each statement +execute procedure refresh_post_like(); + +-- community +create or replace function refresh_community() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently post_view; + refresh materialized view concurrently community_view; + return null; +end $$; + +create trigger refresh_community +after insert or update or delete or truncate +on community +for each statement +execute procedure refresh_community(); + +-- community_follower +create or replace function refresh_community_follower() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently community_view; + refresh materialized view concurrently post_view; + return null; +end $$; + +create trigger refresh_community_follower +after insert or update or delete or truncate +on community_follower +for each statement +execute procedure refresh_community_follower(); + +-- comment +create or replace function refresh_comment() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently post_view; + refresh materialized view concurrently comment_view; + return null; +end $$; + +create trigger refresh_comment +after insert or update or delete or truncate +on comment +for each statement +execute procedure refresh_comment(); + +-- comment_like +create or replace function refresh_comment_like() +returns trigger language plpgsql +as $$ +begin + refresh materialized view concurrently comment_view; + return null; +end $$; + +create trigger refresh_comment_like +after insert or update or delete or truncate +on comment_like +for each statement +execute procedure refresh_comment_like(); diff --git a/server/query_testing/apache_bench_report.sh b/server/query_testing/apache_bench_report.sh index 95b9a6c4c..c22af7308 100755 --- a/server/query_testing/apache_bench_report.sh +++ b/server/query_testing/apache_bench_report.sh @@ -7,6 +7,7 @@ declare -a arr=( "https://dev.lemmy.ml/feeds/all.xml" "https://dev.lemmy.ml/.well-known/nodeinfo" "https://fediverse.blog/.well-known/nodeinfo" +"https://torrents-csv.ml/service/search?q=wheel&page=1&type_=torrent" ) ## now loop through the above array diff --git a/server/query_testing/generate_explain_reports.sh b/server/query_testing/generate_explain_reports.sh index 40b2bceea..9ba910362 100755 --- a/server/query_testing/generate_explain_reports.sh +++ b/server/query_testing/generate_explain_reports.sh @@ -2,19 +2,16 @@ # Do the views first -echo "explain (analyze, format json) select * from user_view" > explain.sql +echo "explain (analyze, format json) select * from user_mview" > explain.sql psql -qAt -U lemmy -f explain.sql > user_view.json -echo "explain (analyze, format json) select * from post_view where user_id is null order by hot_rank desc" > explain.sql +echo "explain (analyze, format json) select * from post_mview where user_id is null order by hot_rank desc, published desc" > explain.sql psql -qAt -U lemmy -f explain.sql > post_view.json -echo "explain (analyze, format json) select * from post" > explain.sql -psql -qAt -U lemmy -f explain.sql > post.json - -echo "explain (analyze, format json) select * from comment_view where user_id is null" > explain.sql +echo "explain (analyze, format json) select * from comment_mview where user_id is null" > explain.sql psql -qAt -U lemmy -f explain.sql > comment_view.json -echo "explain (analyze, format json) select * from community_view where user_id is null order by hot_rank desc" > explain.sql +echo "explain (analyze, format json) select * from community_mview where user_id is null order by hot_rank desc" > explain.sql psql -qAt -U lemmy -f explain.sql > community_view.json echo "explain (analyze, format json) select * from site_view limit 1" > explain.sql diff --git a/server/src/db/comment_view.rs b/server/src/db/comment_view.rs index ba085af64..3b06e8e34 100644 --- a/server/src/db/comment_view.rs +++ b/server/src/db/comment_view.rs @@ -28,6 +28,32 @@ table! { } } +table! { + comment_mview (id) { + id -> Int4, + creator_id -> Int4, + post_id -> Int4, + parent_id -> Nullable, + content -> Text, + removed -> Bool, + read -> Bool, + published -> Timestamp, + updated -> Nullable, + deleted -> Bool, + community_id -> Int4, + banned -> Bool, + banned_from_community -> Bool, + creator_name -> Varchar, + creator_avatar -> Nullable, + score -> BigInt, + upvotes -> BigInt, + downvotes -> BigInt, + user_id -> Nullable, + my_vote -> Nullable, + saved -> Nullable, + } +} + #[derive( Queryable, Identifiable, PartialEq, Debug, Serialize, Deserialize, QueryableByName, Clone, )] @@ -58,7 +84,7 @@ pub struct CommentView { pub struct CommentQueryBuilder<'a> { conn: &'a PgConnection, - query: super::comment_view::comment_view::BoxedQuery<'a, Pg>, + query: super::comment_view::comment_mview::BoxedQuery<'a, Pg>, sort: &'a SortType, for_post_id: Option, for_creator_id: Option, @@ -71,9 +97,9 @@ pub struct CommentQueryBuilder<'a> { impl<'a> CommentQueryBuilder<'a> { pub fn create(conn: &'a PgConnection) -> Self { - use super::comment_view::comment_view::dsl::*; + use super::comment_view::comment_mview::dsl::*; - let query = comment_view.into_boxed(); + let query = comment_mview.into_boxed(); CommentQueryBuilder { conn, @@ -130,7 +156,7 @@ impl<'a> CommentQueryBuilder<'a> { } pub fn list(self) -> Result, Error> { - use super::comment_view::comment_view::dsl::*; + use super::comment_view::comment_mview::dsl::*; let mut query = self.query; diff --git a/server/src/db/community_view.rs b/server/src/db/community_view.rs index 2d49cd447..95e00c65c 100644 --- a/server/src/db/community_view.rs +++ b/server/src/db/community_view.rs @@ -1,4 +1,4 @@ -use super::community_view::community_view::BoxedQuery; +use super::community_view::community_mview::BoxedQuery; use super::*; use diesel::pg::Pg; @@ -27,6 +27,31 @@ table! { } } +table! { + community_mview (id) { + id -> Int4, + name -> Varchar, + title -> Varchar, + description -> Nullable, + category_id -> Int4, + creator_id -> Int4, + removed -> Bool, + published -> Timestamp, + updated -> Nullable, + deleted -> Bool, + nsfw -> Bool, + creator_name -> Varchar, + creator_avatar -> Nullable, + category_name -> Varchar, + number_of_subscribers -> BigInt, + number_of_posts -> BigInt, + number_of_comments -> BigInt, + hot_rank -> Int4, + user_id -> Nullable, + subscribed -> Nullable, + } +} + table! { community_moderator_view (id) { id -> Int4, @@ -103,9 +128,9 @@ pub struct CommunityQueryBuilder<'a> { impl<'a> CommunityQueryBuilder<'a> { pub fn create(conn: &'a PgConnection) -> Self { - use super::community_view::community_view::dsl::*; + use super::community_view::community_mview::dsl::*; - let query = community_view.into_boxed(); + let query = community_mview.into_boxed(); CommunityQueryBuilder { conn, @@ -150,7 +175,7 @@ impl<'a> CommunityQueryBuilder<'a> { } pub fn list(self) -> Result, Error> { - use super::community_view::community_view::dsl::*; + use super::community_view::community_mview::dsl::*; let mut query = self.query; diff --git a/server/src/db/post_view.rs b/server/src/db/post_view.rs index 5217e73a7..f6cc274f0 100644 --- a/server/src/db/post_view.rs +++ b/server/src/db/post_view.rs @@ -1,4 +1,4 @@ -use super::post_view::post_view::BoxedQuery; +use super::post_view::post_mview::BoxedQuery; use super::*; use diesel::pg::Pg; @@ -77,6 +77,43 @@ pub struct PostView { pub saved: Option, } +// The faked schema since diesel doesn't do views +table! { + post_mview (id) { + id -> Int4, + name -> Varchar, + url -> Nullable, + body -> Nullable, + creator_id -> Int4, + community_id -> Int4, + removed -> Bool, + locked -> Bool, + published -> Timestamp, + updated -> Nullable, + deleted -> Bool, + nsfw -> Bool, + banned -> Bool, + banned_from_community -> Bool, + stickied -> Bool, + creator_name -> Varchar, + creator_avatar -> Nullable, + community_name -> Varchar, + community_removed -> Bool, + community_deleted -> Bool, + community_nsfw -> Bool, + number_of_comments -> BigInt, + score -> BigInt, + upvotes -> BigInt, + downvotes -> BigInt, + hot_rank -> Int4, + user_id -> Nullable, + my_vote -> Nullable, + subscribed -> Nullable, + read -> Nullable, + saved -> Nullable, + } +} + pub struct PostQueryBuilder<'a> { conn: &'a PgConnection, query: BoxedQuery<'a, Pg>, @@ -93,9 +130,9 @@ pub struct PostQueryBuilder<'a> { impl<'a> PostQueryBuilder<'a> { pub fn create(conn: &'a PgConnection) -> Self { - use super::post_view::post_view::dsl::*; + use super::post_view::post_mview::dsl::*; - let query = post_view.into_boxed(); + let query = post_mview.into_boxed(); PostQueryBuilder { conn, @@ -123,7 +160,7 @@ impl<'a> PostQueryBuilder<'a> { } pub fn for_community_id>(mut self, for_community_id: T) -> Self { - use super::post_view::post_view::dsl::*; + use super::post_view::post_mview::dsl::*; if let Some(for_community_id) = for_community_id.get_optional() { self.query = self.query.filter(community_id.eq(for_community_id)); self.query = self.query.then_order_by(stickied.desc()); @@ -139,7 +176,7 @@ impl<'a> PostQueryBuilder<'a> { } pub fn search_term>(mut self, search_term: T) -> Self { - use super::post_view::post_view::dsl::*; + use super::post_view::post_mview::dsl::*; if let Some(search_term) = search_term.get_optional() { self.query = self.query.filter(name.ilike(fuzzy_search(&search_term))); } @@ -147,7 +184,7 @@ impl<'a> PostQueryBuilder<'a> { } pub fn url_search>(mut self, url_search: T) -> Self { - use super::post_view::post_view::dsl::*; + use super::post_view::post_mview::dsl::*; if let Some(url_search) = url_search.get_optional() { self.query = self.query.filter(url.eq(url_search)); } @@ -185,7 +222,7 @@ impl<'a> PostQueryBuilder<'a> { } pub fn list(self) -> Result, Error> { - use super::post_view::post_view::dsl::*; + use super::post_view::post_mview::dsl::*; let mut query = self.query; diff --git a/server/src/db/user_view.rs b/server/src/db/user_view.rs index e0de22307..23e47d4be 100644 --- a/server/src/db/user_view.rs +++ b/server/src/db/user_view.rs @@ -1,4 +1,4 @@ -use super::user_view::user_view::BoxedQuery; +use super::user_view::user_mview::BoxedQuery; use super::*; use diesel::pg::Pg; @@ -21,6 +21,25 @@ table! { } } +table! { + user_mview (id) { + id -> Int4, + name -> Varchar, + avatar -> Nullable, + email -> Nullable, + fedi_name -> Varchar, + admin -> Bool, + banned -> Bool, + show_avatars -> Bool, + send_notifications_to_email -> Bool, + published -> Timestamp, + number_of_posts -> BigInt, + post_score -> BigInt, + number_of_comments -> BigInt, + comment_score -> BigInt, + } +} + #[derive( Queryable, Identifiable, PartialEq, Debug, Serialize, Deserialize, QueryableByName, Clone, )] @@ -52,9 +71,9 @@ pub struct UserQueryBuilder<'a> { impl<'a> UserQueryBuilder<'a> { pub fn create(conn: &'a PgConnection) -> Self { - use super::user_view::user_view::dsl::*; + use super::user_view::user_mview::dsl::*; - let query = user_view.into_boxed(); + let query = user_mview.into_boxed(); UserQueryBuilder { conn, @@ -71,7 +90,7 @@ impl<'a> UserQueryBuilder<'a> { } pub fn search_term>(mut self, search_term: T) -> Self { - use super::user_view::user_view::dsl::*; + use super::user_view::user_mview::dsl::*; if let Some(search_term) = search_term.get_optional() { self.query = self.query.filter(name.ilike(fuzzy_search(&search_term))); } @@ -89,7 +108,7 @@ impl<'a> UserQueryBuilder<'a> { } pub fn list(self) -> Result, Error> { - use super::user_view::user_view::dsl::*; + use super::user_view::user_mview::dsl::*; let mut query = self.query; @@ -128,12 +147,12 @@ impl UserView { } pub fn admins(conn: &PgConnection) -> Result, Error> { - use super::user_view::user_view::dsl::*; - user_view.filter(admin.eq(true)).load::(conn) + use super::user_view::user_mview::dsl::*; + user_mview.filter(admin.eq(true)).load::(conn) } pub fn banned(conn: &PgConnection) -> Result, Error> { - use super::user_view::user_view::dsl::*; - user_view.filter(banned.eq(true)).load::(conn) + use super::user_view::user_mview::dsl::*; + user_mview.filter(banned.eq(true)).load::(conn) } } diff --git a/server/src/routes/websocket.rs b/server/src/routes/websocket.rs index 0d953d243..f5e24e48c 100644 --- a/server/src/routes/websocket.rs +++ b/server/src/routes/websocket.rs @@ -141,7 +141,7 @@ impl StreamHandler> for WSSession { } ws::Message::Text(text) => { let m = text.trim().to_owned(); - // println!("WEBSOCKET MESSAGE: {:?} from id: {}", &m, self.id); + println!("WEBSOCKET MESSAGE: {:?} from id: {}", &m, self.id); self .cs_addr