* One pass at materialized views, only about 30% faster, not good.
* Before merging master to test out bans.
* DB Rework working, still need more testing.
* Fixing accidental addadmin bug from asonix async merge.
* Fixing the comment delete trigger
* Some more DB additions.
- Adding a hot_rank desc, published desc index to post_aggregates_fast.
- Removed WITH CTE queries in favor of direct selects (since CTEs cant
use indexes)
* Removing some unecessary indexes.
* 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.
* Adding community_agg_view and post_agg_views Credit: eiknat.
* Adding user and comment_view migrations. (comment_view still broken)
* Adding more views. Credit Eiknat.
--- /dev/null
+-- Dropping all the fast tables
+drop table user_fast;
+drop view post_fast_view;
+drop table post_aggregates_fast;
+drop view community_fast_view;
+drop table community_aggregates_fast;
+drop view reply_fast_view;
+drop view user_mention_fast_view;
+drop view comment_fast_view;
+drop table comment_aggregates_fast;
+
+-- Re-adding all the triggers, functions, and mviews
+
+-- private message
+create materialized view private_message_mview as select * from private_message_view;
+
+create unique index idx_private_message_mview_id on private_message_mview (id);
+
+
+-- Create the triggers
+create or replace function refresh_private_message()
+returns trigger language plpgsql
+as $$
+begin
+ refresh materialized view concurrently private_message_mview;
+ return null;
+end $$;
+
+create trigger refresh_private_message
+after insert or update or delete or truncate
+on private_message
+for each statement
+execute procedure refresh_private_message();
+
+-- 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 $$;
+
+drop trigger refresh_user on user_;
+create trigger refresh_user
+after insert or update or delete or truncate
+on user_
+for each statement
+execute procedure refresh_user();
+drop view user_view cascade;
+
+create view user_view as
+select
+u.id,
+u.actor_id,
+u.name,
+u.avatar,
+u.email,
+u.matrix_user_id,
+u.bio,
+u.local,
+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
+drop trigger refresh_community on community;
+create trigger refresh_community
+after insert or update or delete or truncate
+on community
+for each statement
+execute procedure refresh_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 $$;
+
+drop view community_aggregates_view cascade;
+create view community_aggregates_view as
+-- Now that there's public and private keys, you have to be explicit here
+select c.id,
+c.name,
+c.title,
+c.description,
+c.category_id,
+c.creator_id,
+c.removed,
+c.published,
+c.updated,
+c.deleted,
+c.nsfw,
+c.actor_id,
+c.local,
+c.last_refreshed_at,
+(select actor_id from user_ u where c.creator_id = u.id) as creator_actor_id,
+(select local from user_ u where c.creator_id = u.id) as creator_local,
+(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);
+
+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
+;
+-- Post
+drop view post_view;
+drop view post_aggregates_view;
+
+-- regen post view
+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 actor_id from user_ where p.creator_id = user_.id) as creator_actor_id,
+(select local from user_ where p.creator_id = user_.id) as creator_local,
+(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 actor_id from community where p.community_id = community.id) as community_actor_id,
+(select local from community where p.community_id = community.id) as community_local,
+(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),
+ (
+ case when (p.published < ('now'::timestamp - '1 month'::interval)) then p.published -- Prevents necro-bumps
+ else greatest(c.recent_comment_time, p.published)
+ end
+ )
+) as hot_rank,
+(
+ case when (p.published < ('now'::timestamp - '1 month'::interval)) then p.published -- Prevents necro-bumps
+ else greatest(c.recent_comment_time, p.published)
+ end
+) as newest_activity_time
+from post p
+left join post_like pl on p.id = pl.post_id
+left join (
+ select post_id,
+ max(published) as recent_comment_time
+ from comment
+ group by 1
+) c on p.id = c.post_id
+group by p.id, c.recent_comment_time;
+
+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);
+
+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
+;
+
+drop trigger refresh_post on post;
+create trigger refresh_post
+after insert or update or delete or truncate
+on post
+for each statement
+execute procedure refresh_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 $$;
+
+
+-- User mention, comment, reply
+drop view user_mention_view;
+drop view comment_view;
+drop view comment_aggregates_view;
+
+-- 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 co.actor_id from post p, community co where p.id = c.post_id and p.community_id = co.id) as community_actor_id,
+(select co.local from post p, community co where p.id = c.post_id and p.community_id = co.id) as community_local,
+(select co.name from post p, community co where p.id = c.post_id and p.community_id = co.id) as community_name,
+(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 actor_id from user_ where c.creator_id = user_.id) as creator_actor_id,
+(select local from user_ where c.creator_id = user_.id) as creator_local,
+(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,
+hot_rank(coalesce(sum(cl.score) , 0), c.published) as hot_rank
+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);
+
+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 cf.id::boolean from community_follower cf where u.id = cf.user_id and ac.community_id = cf.community_id) as subscribed,
+(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 subscribed,
+ 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 cf.id::boolean from community_follower cf where u.id = cf.user_id and ac.community_id = cf.community_id) as subscribed,
+(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 subscribed,
+ null as saved
+from all_comment ac
+;
+
+-- Do the reply_view referencing the comment_mview
+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_mview 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.creator_actor_id,
+ c.creator_local,
+ c.post_id,
+ c.parent_id,
+ c.content,
+ c.removed,
+ um.read,
+ c.published,
+ c.updated,
+ c.deleted,
+ c.community_id,
+ c.community_actor_id,
+ c.community_local,
+ c.community_name,
+ c.banned,
+ c.banned_from_community,
+ c.creator_name,
+ c.creator_avatar,
+ c.score,
+ c.upvotes,
+ c.downvotes,
+ c.hot_rank,
+ c.user_id,
+ c.my_vote,
+ c.saved,
+ um.recipient_id,
+ (select actor_id from user_ u where u.id = um.recipient_id) as recipient_actor_id,
+ (select local from user_ u where u.id = um.recipient_id) as recipient_local
+from user_mention um, comment_view c
+where um.comment_id = c.id;
+
+
+create view user_mention_mview as
+with all_comment as
+(
+ select
+ ca.*
+ from comment_aggregates_mview ca
+)
+
+select
+ ac.id,
+ um.id as user_mention_id,
+ ac.creator_id,
+ ac.creator_actor_id,
+ ac.creator_local,
+ ac.post_id,
+ ac.parent_id,
+ ac.content,
+ ac.removed,
+ um.read,
+ ac.published,
+ ac.updated,
+ ac.deleted,
+ ac.community_id,
+ ac.community_actor_id,
+ ac.community_local,
+ ac.community_name,
+ ac.banned,
+ ac.banned_from_community,
+ ac.creator_name,
+ ac.creator_avatar,
+ ac.score,
+ ac.upvotes,
+ ac.downvotes,
+ ac.hot_rank,
+ 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,
+ um.recipient_id,
+ (select actor_id from user_ u where u.id = um.recipient_id) as recipient_actor_id,
+ (select local from user_ u where u.id = um.recipient_id) as recipient_local
+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
+left join user_mention um on um.comment_id = ac.id
+
+union all
+
+select
+ ac.id,
+ um.id as user_mention_id,
+ ac.creator_id,
+ ac.creator_actor_id,
+ ac.creator_local,
+ ac.post_id,
+ ac.parent_id,
+ ac.content,
+ ac.removed,
+ um.read,
+ ac.published,
+ ac.updated,
+ ac.deleted,
+ ac.community_id,
+ ac.community_actor_id,
+ ac.community_local,
+ ac.community_name,
+ ac.banned,
+ ac.banned_from_community,
+ ac.creator_name,
+ ac.creator_avatar,
+ ac.score,
+ ac.upvotes,
+ ac.downvotes,
+ ac.hot_rank,
+ null as user_id,
+ null as my_vote,
+ null as saved,
+ um.recipient_id,
+ (select actor_id from user_ u where u.id = um.recipient_id) as recipient_actor_id,
+ (select local from user_ u where u.id = um.recipient_id) as recipient_local
+from all_comment ac
+left join user_mention um on um.comment_id = ac.id
+;
+
--- /dev/null
+-- Drop the mviews
+drop view post_mview;
+drop materialized view user_mview;
+drop view community_mview;
+drop materialized view private_message_mview;
+drop view user_mention_mview;
+drop view reply_view;
+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
+drop view user_view;
+create view user_view as
+select
+ u.id,
+ u.actor_id,
+ u.name,
+ u.avatar,
+ u.email,
+ u.matrix_user_id,
+ u.bio,
+ u.local,
+ u.admin,
+ u.banned,
+ u.show_avatars,
+ u.send_notifications_to_email,
+ u.published,
+ coalesce(pd.posts, 0) as number_of_posts,
+ coalesce(pd.score, 0) as post_score,
+ coalesce(cd.comments, 0) as number_of_comments,
+ coalesce(cd.score, 0) as comment_score
+from user_ u
+left join (
+ select
+ p.creator_id as creator_id,
+ count(distinct p.id) as posts,
+ sum(pl.score) as score
+ from post p
+ join post_like pl on p.id = pl.post_id
+ group by p.creator_id
+) pd on u.id = pd.creator_id
+left join (
+ select
+ c.creator_id,
+ count(distinct c.id) as comments,
+ sum(cl.score) as score
+ from comment c
+ join comment_like cl on c.id = cl.comment_id
+ group by c.creator_id
+) cd on u.id = cd.creator_id;
+
+
+create table user_fast as select * from user_view;
+alter table user_fast add primary key (id);
+
+drop trigger refresh_user on user_;
+
+create trigger refresh_user
+after insert or update or delete
+on user_
+for each row
+execute procedure refresh_user();
+
+-- Sample insert
+-- insert into user_(name, password_encrypted) values ('test_name', 'bleh');
+-- Sample delete
+-- delete from user_ where name like 'test_name';
+-- Sample update
+-- update user_ set avatar = 'hai' where name like 'test_name';
+create or replace function refresh_user()
+returns trigger language plpgsql
+as $$
+begin
+ IF (TG_OP = 'DELETE') THEN
+ delete from user_fast where id = OLD.id;
+ ELSIF (TG_OP = 'UPDATE') THEN
+ delete from user_fast where id = OLD.id;
+ insert into user_fast select * from user_view where id = NEW.id;
+
+ -- Refresh post_fast, cause of user info changes
+ delete from post_aggregates_fast where creator_id = NEW.id;
+ insert into post_aggregates_fast select * from post_aggregates_view where creator_id = NEW.id;
+
+ delete from comment_aggregates_fast where creator_id = NEW.id;
+ insert into comment_aggregates_fast select * from comment_aggregates_view where creator_id = NEW.id;
+
+ ELSIF (TG_OP = 'INSERT') THEN
+ insert into user_fast select * from user_view where id = NEW.id;
+ END IF;
+
+ return null;
+end $$;
+
+-- Post
+-- Redoing the views : Credit eiknat
+drop view post_view;
+drop view post_aggregates_view;
+
+create view post_aggregates_view as
+select
+ p.*,
+ -- creator details
+ u.actor_id as creator_actor_id,
+ u."local" as creator_local,
+ u."name" as creator_name,
+ u.avatar as creator_avatar,
+ u.banned as banned,
+ cb.id::bool as banned_from_community,
+ -- community details
+ c.actor_id as community_actor_id,
+ c."local" as community_local,
+ c."name" as community_name,
+ c.removed as community_removed,
+ c.deleted as community_deleted,
+ c.nsfw as community_nsfw,
+ -- post score data/comment count
+ coalesce(ct.comments, 0) as number_of_comments,
+ coalesce(pl.score, 0) as score,
+ coalesce(pl.upvotes, 0) as upvotes,
+ coalesce(pl.downvotes, 0) as downvotes,
+ hot_rank(
+ coalesce(pl.score , 0), (
+ case
+ when (p.published < ('now'::timestamp - '1 month'::interval))
+ then p.published
+ else greatest(ct.recent_comment_time, p.published)
+ end
+ )
+ ) as hot_rank,
+ (
+ case
+ when (p.published < ('now'::timestamp - '1 month'::interval))
+ then p.published
+ else greatest(ct.recent_comment_time, p.published)
+ end
+ ) as newest_activity_time
+from post p
+left join user_ u on p.creator_id = u.id
+left join community_user_ban cb on p.creator_id = cb.user_id and p.community_id = cb.community_id
+left join community c on p.community_id = c.id
+left join (
+ select
+ post_id,
+ count(*) as comments,
+ max(published) as recent_comment_time
+ from comment
+ group by post_id
+) ct on ct.post_id = p.id
+left join (
+ select
+ post_id,
+ sum(score) as score,
+ sum(score) filter (where score = 1) as upvotes,
+ -sum(score) filter (where score = -1) as downvotes
+ from post_like
+ group by post_id
+) pl on pl.post_id = p.id
+order by p.id;
+
+create view post_view as
+select
+ pav.*,
+ us.id as user_id,
+ us.user_vote as my_vote,
+ us.is_subbed::bool as subscribed,
+ us.is_read::bool as read,
+ us.is_saved::bool as saved
+from post_aggregates_view pav
+cross join lateral (
+ select
+ u.id,
+ coalesce(cf.community_id, 0) as is_subbed,
+ coalesce(pr.post_id, 0) as is_read,
+ coalesce(ps.post_id, 0) as is_saved,
+ coalesce(pl.score, 0) as user_vote
+ from user_ u
+ left join community_user_ban cb on u.id = cb.user_id and cb.community_id = pav.community_id
+ left join community_follower cf on u.id = cf.user_id and cf.community_id = pav.community_id
+ left join post_read pr on u.id = pr.user_id and pr.post_id = pav.id
+ left join post_saved ps on u.id = ps.user_id and ps.post_id = pav.id
+ left join post_like pl on u.id = pl.user_id and pav.id = pl.post_id
+) as us
+
+union all
+
+select
+pav.*,
+null as user_id,
+null as my_vote,
+null as subscribed,
+null as read,
+null as saved
+from post_aggregates_view pav;
+
+-- The post fast table
+create table post_aggregates_fast as select * from post_aggregates_view;
+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);
+
+create view post_fast_view as
+select
+ pav.*,
+ us.id as user_id,
+ us.user_vote as my_vote,
+ us.is_subbed::bool as subscribed,
+ us.is_read::bool as read,
+ us.is_saved::bool as saved
+from post_aggregates_fast pav
+cross join lateral (
+ select
+ u.id,
+ coalesce(cf.community_id, 0) as is_subbed,
+ coalesce(pr.post_id, 0) as is_read,
+ coalesce(ps.post_id, 0) as is_saved,
+ coalesce(pl.score, 0) as user_vote
+ from user_ u
+ left join community_user_ban cb on u.id = cb.user_id and cb.community_id = pav.community_id
+ left join community_follower cf on u.id = cf.user_id and cf.community_id = pav.community_id
+ left join post_read pr on u.id = pr.user_id and pr.post_id = pav.id
+ left join post_saved ps on u.id = ps.user_id and ps.post_id = pav.id
+ left join post_like pl on u.id = pl.user_id and pav.id = pl.post_id
+) as us
+
+union all
+
+select
+pav.*,
+null as user_id,
+null as my_vote,
+null as subscribed,
+null as read,
+null as saved
+from post_aggregates_fast pav;
+
+drop trigger refresh_post on post;
+
+create trigger refresh_post
+after insert or update or delete
+on post
+for each row
+execute procedure refresh_post();
+
+-- Sample select
+-- select id, name from post_fast_view where name like 'test_post' and user_id is null;
+-- Sample insert
+-- insert into post(name, creator_id, community_id) values ('test_post', 2, 2);
+-- Sample delete
+-- delete from post where name like 'test_post';
+-- Sample update
+-- update post set community_id = 4 where name like 'test_post';
+create or replace function refresh_post()
+returns trigger language plpgsql
+as $$
+begin
+ IF (TG_OP = 'DELETE') THEN
+ delete from post_aggregates_fast where id = OLD.id;
+
+ -- Update community number of posts
+ update community_aggregates_fast set number_of_posts = number_of_posts - 1 where id = OLD.community_id;
+ ELSIF (TG_OP = 'UPDATE') THEN
+ delete from post_aggregates_fast where id = OLD.id;
+ insert into post_aggregates_fast select * from post_aggregates_view where id = NEW.id;
+ ELSIF (TG_OP = 'INSERT') THEN
+ insert into post_aggregates_fast select * from post_aggregates_view where id = NEW.id;
+
+ -- Update that users number of posts, post score
+ delete from user_fast where id = NEW.creator_id;
+ insert into user_fast select * from user_view where id = NEW.creator_id;
+
+ -- Update community number of posts
+ update community_aggregates_fast set number_of_posts = number_of_posts + 1 where id = NEW.community_id;
+
+ -- Update the hot rank on the post table
+ -- TODO this might not correctly update it, using a 1 week interval
+ update post_aggregates_fast as paf
+ set hot_rank = pav.hot_rank
+ from post_aggregates_view as pav
+ where paf.id = pav.id and (pav.published > ('now'::timestamp - '1 week'::interval));
+ END IF;
+
+ return null;
+end $$;
+
+-- Community
+-- Redoing the views : Credit eiknat
+drop view community_moderator_view;
+drop view community_follower_view;
+drop view community_user_ban_view;
+drop view community_view;
+drop view community_aggregates_view;
+
+create view community_aggregates_view as
+select
+ c.id,
+ c.name,
+ c.title,
+ c.description,
+ c.category_id,
+ c.creator_id,
+ c.removed,
+ c.published,
+ c.updated,
+ c.deleted,
+ c.nsfw,
+ c.actor_id,
+ c.local,
+ c.last_refreshed_at,
+ u.actor_id as creator_actor_id,
+ u.local as creator_local,
+ u.name as creator_name,
+ u.avatar as creator_avatar,
+ cat.name as category_name,
+ coalesce(cf.subs, 0) as number_of_subscribers,
+ coalesce(cd.posts, 0) as number_of_posts,
+ coalesce(cd.comments, 0) as number_of_comments,
+ hot_rank(cf.subs, c.published) as hot_rank
+from community c
+left join user_ u on c.creator_id = u.id
+left join category cat on c.category_id = cat.id
+left join (
+ select
+ p.community_id,
+ count(distinct p.id) as posts,
+ count(distinct ct.id) as comments
+ from post p
+ join comment ct on p.id = ct.post_id
+ group by p.community_id
+) cd on cd.community_id = c.id
+left join (
+ select
+ community_id,
+ count(*) as subs
+ from community_follower
+ group by community_id
+) cf on cf.community_id = c.id;
+
+create view community_view as
+select
+ cv.*,
+ us.user as user_id,
+ us.is_subbed::bool as subscribed
+from community_aggregates_view cv
+cross join lateral (
+ select
+ u.id as user,
+ coalesce(cf.community_id, 0) as is_subbed
+ from user_ u
+ left join community_follower cf on u.id = cf.user_id and cf.community_id = cv.id
+) as us
+
+union all
+
+select
+ cv.*,
+ null as user_id,
+ null as subscribed
+from community_aggregates_view cv;
+
+create view community_moderator_view as
+select
+ cm.*,
+ u.actor_id as user_actor_id,
+ u.local as user_local,
+ u.name as user_name,
+ u.avatar as avatar,
+ c.actor_id as community_actor_id,
+ c.local as community_local,
+ c.name as community_name
+from community_moderator cm
+left join user_ u on cm.user_id = u.id
+left join community c on cm.community_id = c.id;
+
+create view community_follower_view as
+select
+ cf.*,
+ u.actor_id as user_actor_id,
+ u.local as user_local,
+ u.name as user_name,
+ u.avatar as avatar,
+ c.actor_id as community_actor_id,
+ c.local as community_local,
+ c.name as community_name
+from community_follower cf
+left join user_ u on cf.user_id = u.id
+left join community c on cf.community_id = c.id;
+
+create view community_user_ban_view as
+select
+ cb.*,
+ u.actor_id as user_actor_id,
+ u.local as user_local,
+ u.name as user_name,
+ u.avatar as avatar,
+ c.actor_id as community_actor_id,
+ c.local as community_local,
+ c.name as community_name
+from community_user_ban cb
+left join user_ u on cb.user_id = u.id
+left join community c on cb.community_id = c.id;
+
+-- The community fast table
+
+create table community_aggregates_fast as select * from community_aggregates_view;
+alter table community_aggregates_fast add primary key (id);
+
+create view community_fast_view as
+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 (
+ select
+ ca.*
+ from community_aggregates_fast ca
+) ac
+
+union all
+
+select
+caf.*,
+null as user_id,
+null as subscribed
+from community_aggregates_fast caf;
+
+drop trigger refresh_community on community;
+
+create trigger refresh_community
+after insert or update or delete
+on community
+for each row
+execute procedure refresh_community();
+
+-- Sample select
+-- select * from community_fast_view where name like 'test_community_name' and user_id is null;
+-- Sample insert
+-- insert into community(name, title, category_id, creator_id) values ('test_community_name', 'test_community_title', 1, 2);
+-- Sample delete
+-- delete from community where name like 'test_community_name';
+-- Sample update
+-- update community set title = 'test_community_title_2' where name like 'test_community_name';
+create or replace function refresh_community()
+returns trigger language plpgsql
+as $$
+begin
+ IF (TG_OP = 'DELETE') THEN
+ delete from community_aggregates_fast where id = OLD.id;
+ ELSIF (TG_OP = 'UPDATE') THEN
+ delete from community_aggregates_fast where id = OLD.id;
+ insert into community_aggregates_fast select * from community_aggregates_view where id = NEW.id;
+
+ -- Update user view due to owner changes
+ delete from user_fast where id = NEW.creator_id;
+ insert into user_fast select * from user_view where id = NEW.creator_id;
+
+ -- Update post view due to community changes
+ delete from post_aggregates_fast where community_id = NEW.id;
+ insert into post_aggregates_fast select * from post_aggregates_view where community_id = NEW.id;
+
+ -- TODO make sure this shows up in the users page ?
+ ELSIF (TG_OP = 'INSERT') THEN
+ insert into community_aggregates_fast select * from community_aggregates_view where id = NEW.id;
+ END IF;
+
+ return null;
+end $$;
+
+-- Comment
+
+drop view user_mention_view;
+drop view comment_view;
+drop view comment_aggregates_view;
+
+create view comment_aggregates_view as
+select
+ ct.*,
+ -- community details
+ p.community_id,
+ c.actor_id as community_actor_id,
+ c."local" as community_local,
+ c."name" as community_name,
+ -- creator details
+ u.banned as banned,
+ coalesce(cb.id, 0)::bool as banned_from_community,
+ u.actor_id as creator_actor_id,
+ u.local as creator_local,
+ u.name as creator_name,
+ u.avatar as creator_avatar,
+ -- score details
+ coalesce(cl.total, 0) as score,
+ coalesce(cl.up, 0) as upvotes,
+ coalesce(cl.down, 0) as downvotes,
+ hot_rank(coalesce(cl.total, 0), ct.published) as hot_rank
+from comment ct
+left join post p on ct.post_id = p.id
+left join community c on p.community_id = c.id
+left join user_ u on ct.creator_id = u.id
+left join community_user_ban cb on ct.creator_id = cb.user_id and p.id = ct.post_id and p.community_id = cb.community_id
+left join (
+ select
+ l.comment_id as id,
+ sum(l.score) as total,
+ count(case when l.score = 1 then 1 else null end) as up,
+ count(case when l.score = -1 then 1 else null end) as down
+ from comment_like l
+ group by comment_id
+) as cl on cl.id = ct.id;
+
+create or replace view comment_view as (
+select
+ cav.*,
+ us.user_id as user_id,
+ us.my_vote as my_vote,
+ us.is_subbed::bool as subscribed,
+ us.is_saved::bool as saved
+from comment_aggregates_view cav
+cross join lateral (
+ select
+ u.id as user_id,
+ coalesce(cl.score, 0) as my_vote,
+ coalesce(cf.id, 0) as is_subbed,
+ coalesce(cs.id, 0) as is_saved
+ from user_ u
+ left join comment_like cl on u.id = cl.user_id and cav.id = cl.comment_id
+ left join comment_saved cs on u.id = cs.user_id and cs.comment_id = cav.id
+ left join community_follower cf on u.id = cf.user_id and cav.community_id = cf.community_id
+) as us
+
+union all
+
+select
+ cav.*,
+ null as user_id,
+ null as my_vote,
+ null as subscribed,
+ null as saved
+from comment_aggregates_view cav
+);
+
+-- The fast view
+create table comment_aggregates_fast as select * from comment_aggregates_view;
+alter table comment_aggregates_fast add primary key (id);
+
+create view comment_fast_view as
+select
+ cav.*,
+ us.user_id as user_id,
+ us.my_vote as my_vote,
+ us.is_subbed::bool as subscribed,
+ us.is_saved::bool as saved
+from comment_aggregates_fast cav
+cross join lateral (
+ select
+ u.id as user_id,
+ coalesce(cl.score, 0) as my_vote,
+ coalesce(cf.id, 0) as is_subbed,
+ coalesce(cs.id, 0) as is_saved
+ from user_ u
+ left join comment_like cl on u.id = cl.user_id and cav.id = cl.comment_id
+ left join comment_saved cs on u.id = cs.user_id and cs.comment_id = cav.id
+ left join community_follower cf on u.id = cf.user_id and cav.community_id = cf.community_id
+) as us
+
+union all
+
+select
+ cav.*,
+ null as user_id,
+ null as my_vote,
+ null as subscribed,
+ null as saved
+from comment_aggregates_fast cav;
+
+-- Do the reply_view referencing the comment_fast_view
+create view reply_fast_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_fast_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.creator_actor_id,
+ c.creator_local,
+ c.post_id,
+ c.parent_id,
+ c.content,
+ c.removed,
+ um.read,
+ c.published,
+ c.updated,
+ c.deleted,
+ c.community_id,
+ c.community_actor_id,
+ c.community_local,
+ c.community_name,
+ c.banned,
+ c.banned_from_community,
+ c.creator_name,
+ c.creator_avatar,
+ c.score,
+ c.upvotes,
+ c.downvotes,
+ c.hot_rank,
+ c.user_id,
+ c.my_vote,
+ c.saved,
+ um.recipient_id,
+ (select actor_id from user_ u where u.id = um.recipient_id) as recipient_actor_id,
+ (select local from user_ u where u.id = um.recipient_id) as recipient_local
+from user_mention um, comment_view c
+where um.comment_id = c.id;
+
+create view user_mention_fast_view as
+select
+ ac.id,
+ um.id as user_mention_id,
+ ac.creator_id,
+ ac.creator_actor_id,
+ ac.creator_local,
+ ac.post_id,
+ ac.parent_id,
+ ac.content,
+ ac.removed,
+ um.read,
+ ac.published,
+ ac.updated,
+ ac.deleted,
+ ac.community_id,
+ ac.community_actor_id,
+ ac.community_local,
+ ac.community_name,
+ ac.banned,
+ ac.banned_from_community,
+ ac.creator_name,
+ ac.creator_avatar,
+ ac.score,
+ ac.upvotes,
+ ac.downvotes,
+ ac.hot_rank,
+ 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,
+ um.recipient_id,
+ (select actor_id from user_ u where u.id = um.recipient_id) as recipient_actor_id,
+ (select local from user_ u where u.id = um.recipient_id) as recipient_local
+from user_ u
+cross join (
+ select
+ ca.*
+ from comment_aggregates_fast ca
+) ac
+left join comment_like cl on u.id = cl.user_id and ac.id = cl.comment_id
+left join user_mention um on um.comment_id = ac.id
+
+union all
+
+select
+ ac.id,
+ um.id as user_mention_id,
+ ac.creator_id,
+ ac.creator_actor_id,
+ ac.creator_local,
+ ac.post_id,
+ ac.parent_id,
+ ac.content,
+ ac.removed,
+ um.read,
+ ac.published,
+ ac.updated,
+ ac.deleted,
+ ac.community_id,
+ ac.community_actor_id,
+ ac.community_local,
+ ac.community_name,
+ ac.banned,
+ ac.banned_from_community,
+ ac.creator_name,
+ ac.creator_avatar,
+ ac.score,
+ ac.upvotes,
+ ac.downvotes,
+ ac.hot_rank,
+ null as user_id,
+ null as my_vote,
+ null as saved,
+ um.recipient_id,
+ (select actor_id from user_ u where u.id = um.recipient_id) as recipient_actor_id,
+ (select local from user_ u where u.id = um.recipient_id) as recipient_local
+from comment_aggregates_fast ac
+left join user_mention um on um.comment_id = ac.id
+;
+
+
+drop trigger refresh_comment on comment;
+
+create trigger refresh_comment
+after insert or update or delete
+on comment
+for each row
+execute procedure refresh_comment();
+
+-- Sample select
+-- select * from comment_fast_view where content = 'test_comment' and user_id is null;
+-- Sample insert
+-- insert into comment(creator_id, post_id, content) values (2, 2, 'test_comment');
+-- Sample delete
+-- delete from comment where content like 'test_comment';
+-- Sample update
+-- update comment set removed = true where content like 'test_comment';
+create or replace function refresh_comment()
+returns trigger language plpgsql
+as $$
+begin
+ IF (TG_OP = 'DELETE') THEN
+ delete from comment_aggregates_fast where id = OLD.id;
+
+ -- Update community number of comments
+ update community_aggregates_fast as caf
+ set number_of_comments = number_of_comments - 1
+ from post as p
+ where caf.id = p.community_id and p.id = OLD.post_id;
+
+ ELSIF (TG_OP = 'UPDATE') THEN
+ delete from comment_aggregates_fast where id = OLD.id;
+ insert into comment_aggregates_fast select * from comment_aggregates_view where id = NEW.id;
+ ELSIF (TG_OP = 'INSERT') THEN
+ insert into comment_aggregates_fast select * from comment_aggregates_view where id = NEW.id;
+
+ -- Update user view due to comment count
+ update user_fast
+ set number_of_comments = number_of_comments + 1
+ where id = NEW.creator_id;
+
+ -- Update post view due to comment count, new comment activity time, but only on new posts
+ -- TODO this could be done more efficiently
+ 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;
+
+ -- Force the hot rank as zero on week-older posts
+ update post_aggregates_fast as paf
+ set hot_rank = 0
+ where paf.id = NEW.post_id and (paf.published < ('now'::timestamp - '1 week'::interval));
+
+ -- Update community number of comments
+ update community_aggregates_fast as caf
+ set number_of_comments = number_of_comments + 1
+ from post as p
+ where caf.id = p.community_id and p.id = NEW.post_id;
+
+ END IF;
+
+ return null;
+end $$;
+
+
+-- post_like
+-- select id, score, my_vote from post_fast_view where id = 29 and user_id = 4;
+-- Sample insert
+-- insert into post_like(user_id, post_id, score) values (4, 29, 1);
+-- Sample delete
+-- delete from post_like where user_id = 4 and post_id = 29;
+-- Sample update
+-- update post_like set score = -1 where user_id = 4 and post_id = 29;
+
+-- TODO test this a LOT
+create or replace function refresh_post_like()
+returns trigger language plpgsql
+as $$
+begin
+ IF (TG_OP = 'DELETE') THEN
+ 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
+ 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;
+end $$;
+
+drop trigger refresh_post_like on post_like;
+create trigger refresh_post_like
+after insert or delete
+on post_like
+for each row
+execute procedure refresh_post_like();
+
+-- comment_like
+-- select id, score, my_vote from comment_fast_view where id = 29 and user_id = 4;
+-- Sample insert
+-- insert into comment_like(user_id, comment_id, post_id, score) values (4, 29, 51, 1);
+-- Sample delete
+-- delete from comment_like where user_id = 4 and comment_id = 29;
+-- Sample update
+-- update comment_like set score = -1 where user_id = 4 and comment_id = 29;
+create or replace function refresh_comment_like()
+returns trigger language plpgsql
+as $$
+begin
+ -- TODO possibly select from comment_fast to get previous scores, instead of re-fetching the views?
+ IF (TG_OP = 'DELETE') THEN
+ 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
+ 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;
+end $$;
+
+drop trigger refresh_comment_like on comment_like;
+create trigger refresh_comment_like
+after insert or delete
+on comment_like
+for each row
+execute procedure refresh_comment_like();
+
+-- Community user ban
+
+drop trigger refresh_community_user_ban on community_user_ban;
+create trigger refresh_community_user_ban
+after insert or delete -- Note this is missing after update
+on community_user_ban
+for each row
+execute procedure refresh_community_user_ban();
+
+-- select creator_name, banned_from_community from comment_fast_view where user_id = 4 and content = 'test_before_ban';
+-- select creator_name, banned_from_community, community_id from comment_aggregates_fast where content = 'test_before_ban';
+-- Sample insert
+-- insert into comment(creator_id, post_id, content) values (1198, 341, 'test_before_ban');
+-- insert into community_user_ban(community_id, user_id) values (2, 1198);
+-- Sample delete
+-- delete from community_user_ban where user_id = 1198 and community_id = 2;
+-- delete from comment where content = 'test_before_ban';
+-- update comment_aggregates_fast set banned_from_community = false where creator_id = 1198 and community_id = 2;
+create or replace function refresh_community_user_ban()
+returns trigger language plpgsql
+as $$
+begin
+ -- TODO possibly select from comment_fast to get previous scores, instead of re-fetching the views?
+ IF (TG_OP = 'DELETE') THEN
+ update comment_aggregates_fast set banned_from_community = false where creator_id = OLD.user_id and community_id = OLD.community_id;
+ update post_aggregates_fast set banned_from_community = false where creator_id = OLD.user_id and community_id = OLD.community_id;
+ ELSIF (TG_OP = 'INSERT') THEN
+ update comment_aggregates_fast set banned_from_community = true where creator_id = NEW.user_id and community_id = NEW.community_id;
+ update post_aggregates_fast set banned_from_community = true where creator_id = NEW.user_id and community_id = NEW.community_id;
+ END IF;
+
+ return null;
+end $$;
+
+-- Community follower
+
+drop trigger refresh_community_follower on community_follower;
+create trigger refresh_community_follower
+after insert or delete -- Note this is missing after update
+on community_follower
+for each row
+execute procedure refresh_community_follower();
+
+create or replace function refresh_community_follower()
+returns trigger language plpgsql
+as $$
+begin
+ IF (TG_OP = 'DELETE') THEN
+ update community_aggregates_fast set number_of_subscribers = number_of_subscribers - 1 where id = OLD.community_id;
+ ELSIF (TG_OP = 'INSERT') THEN
+ update community_aggregates_fast set number_of_subscribers = number_of_subscribers + 1 where id = NEW.community_id;
+ END IF;
+
+ return null;
+end $$;
#!/bin/bash
set -e
+# You can import these to http://tatiyants.com/pev/#/plans/new
+
# Do the views first
-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 user_fast" > explain.sql
+psql -qAt -U lemmy -f explain.sql > user_fast.json
-echo "explain (analyze, format json) select * from post_mview where user_id is null order by hot_rank desc, published desc" > explain.sql
+echo "explain (analyze, format json) select * from post_view 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 comment_mview where user_id is null" > explain.sql
+echo "explain (analyze, format json) select * from post_fast_view where user_id is null order by hot_rank desc, published desc" > explain.sql
+psql -qAt -U lemmy -f explain.sql > post_fast_view.json
+
+echo "explain (analyze, format json) select * from comment_view 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_mview where user_id is null order by hot_rank desc" > explain.sql
+echo "explain (analyze, format json) select * from comment_fast_view where user_id is null" > explain.sql
+psql -qAt -U lemmy -f explain.sql > comment_fast_view.json
+
+echo "explain (analyze, format json) select * from community_view 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 community_fast_view where user_id is null order by hot_rank desc" > explain.sql
+psql -qAt -U lemmy -f explain.sql > community_fast_view.json
+
echo "explain (analyze, format json) select * from site_view limit 1" > explain.sql
psql -qAt -U lemmy -f explain.sql > site_view.json
-echo "explain (analyze, format json) select * from reply_view where user_id = 34 and recipient_id = 34" > explain.sql
-psql -qAt -U lemmy -f explain.sql > reply_view.json
+echo "explain (analyze, format json) select * from reply_fast_view where user_id = 34 and recipient_id = 34" > explain.sql
+psql -qAt -U lemmy -f explain.sql > reply_fast_view.json
echo "explain (analyze, format json) select * from user_mention_view where user_id = 34 and recipient_id = 34" > explain.sql
psql -qAt -U lemmy -f explain.sql > user_mention_view.json
-echo "explain (analyze, format json) select * from user_mention_mview where user_id = 34 and recipient_id = 34" > explain.sql
-psql -qAt -U lemmy -f explain.sql > user_mention_mview.json
+echo "explain (analyze, format json) select * from user_mention_fast_view where user_id = 34 and recipient_id = 34" > explain.sql
+psql -qAt -U lemmy -f explain.sql > user_mention_fast_view.json
grep "Execution Time" *.json
}
let added = data.added;
- let add_admin = move |conn: &'_ _| User_::add_admin(conn, user_id, added);
+ let added_user_id = data.user_id;
+ let add_admin = move |conn: &'_ _| User_::add_admin(conn, added_user_id, added);
if blocking(pool, add_admin).await?.is_err() {
return Err(APIError::err("couldnt_update_user").into());
}
.filter(local.eq(true))
.load::<PrivateMessage>(conn)?;
- sql_query("alter table private_message disable trigger refresh_private_message").execute(conn)?;
-
for cpm in &incorrect_pms {
PrivateMessage::update_ap_id(&conn, cpm.id)?;
}
- sql_query("alter table private_message enable trigger refresh_private_message").execute(conn)?;
-
info!("{} private message rows updated.", incorrect_pms.len());
Ok(())
+// 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};
}
table! {
- comment_mview (id) {
+ comment_fast_view (id) {
id -> Int4,
creator_id -> Int4,
post_id -> Int4,
#[derive(
Queryable, Identifiable, PartialEq, Debug, Serialize, Deserialize, QueryableByName, Clone,
)]
-#[table_name = "comment_view"]
+#[table_name = "comment_fast_view"]
pub struct CommentView {
pub id: i32,
pub creator_id: i32,
pub struct CommentQueryBuilder<'a> {
conn: &'a PgConnection,
- query: super::comment_view::comment_mview::BoxedQuery<'a, Pg>,
+ query: super::comment_view::comment_fast_view::BoxedQuery<'a, Pg>,
listing_type: ListingType,
sort: &'a SortType,
for_community_id: Option<i32>,
impl<'a> CommentQueryBuilder<'a> {
pub fn create(conn: &'a PgConnection) -> Self {
- use super::comment_view::comment_mview::dsl::*;
+ use super::comment_view::comment_fast_view::dsl::*;
- let query = comment_mview.into_boxed();
+ let query = comment_fast_view.into_boxed();
CommentQueryBuilder {
conn,
}
pub fn list(self) -> Result<Vec<CommentView>, Error> {
- use super::comment_view::comment_mview::dsl::*;
+ use super::comment_view::comment_fast_view::dsl::*;
let mut query = self.query;
from_comment_id: i32,
my_user_id: Option<i32>,
) -> Result<Self, Error> {
- use super::comment_view::comment_mview::dsl::*;
- let mut query = comment_mview.into_boxed();
+ use super::comment_view::comment_fast_view::dsl::*;
+ let mut query = comment_fast_view.into_boxed();
// The view lets you pass a null user_id, if you're not logged in
if let Some(my_user_id) = my_user_id {
// The faked schema since diesel doesn't do views
table! {
- reply_view (id) {
+ reply_fast_view (id) {
id -> Int4,
creator_id -> Int4,
post_id -> Int4,
#[derive(
Queryable, Identifiable, PartialEq, Debug, Serialize, Deserialize, QueryableByName, Clone,
)]
-#[table_name = "reply_view"]
+#[table_name = "reply_fast_view"]
pub struct ReplyView {
pub id: i32,
pub creator_id: i32,
pub struct ReplyQueryBuilder<'a> {
conn: &'a PgConnection,
- query: super::comment_view::reply_view::BoxedQuery<'a, Pg>,
+ query: super::comment_view::reply_fast_view::BoxedQuery<'a, Pg>,
for_user_id: i32,
sort: &'a SortType,
unread_only: bool,
impl<'a> ReplyQueryBuilder<'a> {
pub fn create(conn: &'a PgConnection, for_user_id: i32) -> Self {
- use super::comment_view::reply_view::dsl::*;
+ use super::comment_view::reply_fast_view::dsl::*;
- let query = reply_view.into_boxed();
+ let query = reply_fast_view.into_boxed();
ReplyQueryBuilder {
conn,
}
pub fn list(self) -> Result<Vec<ReplyView>, Error> {
- use super::comment_view::reply_view::dsl::*;
+ use super::comment_view::reply_fast_view::dsl::*;
let mut query = self.query;
upvotes: 1,
user_id: Some(inserted_user.id),
my_vote: Some(1),
- subscribed: None,
- saved: None,
+ subscribed: Some(false),
+ saved: Some(false),
ap_id: "http://fake.com".to_string(),
local: true,
community_actor_id: inserted_community.actor_id.to_owned(),
-use super::community_view::community_mview::BoxedQuery;
+use super::community_view::community_fast_view::BoxedQuery;
use crate::db::{fuzzy_search, limit_and_offset, MaybeOptional, SortType};
use diesel::{pg::Pg, result::Error, *};
use serde::{Deserialize, Serialize};
}
table! {
- community_mview (id) {
+ community_fast_view (id) {
id -> Int4,
name -> Varchar,
title -> Varchar,
#[derive(
Queryable, Identifiable, PartialEq, Debug, Serialize, Deserialize, QueryableByName, Clone,
)]
-#[table_name = "community_view"]
+#[table_name = "community_fast_view"]
pub struct CommunityView {
pub id: i32,
pub name: String,
impl<'a> CommunityQueryBuilder<'a> {
pub fn create(conn: &'a PgConnection) -> Self {
- use super::community_view::community_mview::dsl::*;
+ use super::community_view::community_fast_view::dsl::*;
- let query = community_mview.into_boxed();
+ let query = community_fast_view.into_boxed();
CommunityQueryBuilder {
conn,
}
pub fn list(self) -> Result<Vec<CommunityView>, Error> {
- use super::community_view::community_mview::dsl::*;
+ use super::community_view::community_fast_view::dsl::*;
let mut query = self.query;
from_community_id: i32,
from_user_id: Option<i32>,
) -> Result<Self, Error> {
- use super::community_view::community_mview::dsl::*;
+ use super::community_view::community_fast_view::dsl::*;
- let mut query = community_mview.into_boxed();
+ let mut query = community_fast_view.into_boxed();
query = query.filter(id.eq(from_community_id));
-use super::post_view::post_mview::BoxedQuery;
+use super::post_view::post_fast_view::BoxedQuery;
use crate::db::{fuzzy_search, limit_and_offset, ListingType, MaybeOptional, SortType};
use diesel::{dsl::*, pg::Pg, result::Error, *};
use serde::{Deserialize, Serialize};
thumbnail_url -> Nullable<Text>,
ap_id -> Text,
local -> Bool,
- banned -> Bool,
- banned_from_community -> Bool,
creator_actor_id -> Text,
creator_local -> Bool,
creator_name -> Varchar,
creator_avatar -> Nullable<Text>,
+ banned -> Bool,
+ banned_from_community -> Bool,
community_actor_id -> Text,
community_local -> Bool,
community_name -> Varchar,
}
table! {
- post_mview (id) {
+ post_fast_view (id) {
id -> Int4,
name -> Varchar,
url -> Nullable<Text>,
thumbnail_url -> Nullable<Text>,
ap_id -> Text,
local -> Bool,
- banned -> Bool,
- banned_from_community -> Bool,
creator_actor_id -> Text,
creator_local -> Bool,
creator_name -> Varchar,
creator_avatar -> Nullable<Text>,
+ banned -> Bool,
+ banned_from_community -> Bool,
community_actor_id -> Text,
community_local -> Bool,
community_name -> Varchar,
#[derive(
Queryable, Identifiable, PartialEq, Debug, Serialize, Deserialize, QueryableByName, Clone,
)]
-#[table_name = "post_view"]
+#[table_name = "post_fast_view"]
pub struct PostView {
pub id: i32,
pub name: String,
pub thumbnail_url: Option<String>,
pub ap_id: String,
pub local: bool,
- pub banned: bool,
- pub banned_from_community: bool,
pub creator_actor_id: String,
pub creator_local: bool,
pub creator_name: String,
pub creator_avatar: Option<String>,
+ pub banned: bool,
+ pub banned_from_community: bool,
pub community_actor_id: String,
pub community_local: bool,
pub community_name: String,
impl<'a> PostQueryBuilder<'a> {
pub fn create(conn: &'a PgConnection) -> Self {
- use super::post_view::post_mview::dsl::*;
+ use super::post_view::post_fast_view::dsl::*;
- let query = post_mview.into_boxed();
+ let query = post_fast_view.into_boxed();
PostQueryBuilder {
conn,
}
pub fn list(self) -> Result<Vec<PostView>, Error> {
- use super::post_view::post_mview::dsl::*;
+ use super::post_view::post_fast_view::dsl::*;
let mut query = self.query;
from_post_id: i32,
my_user_id: Option<i32>,
) -> Result<Self, Error> {
- use super::post_view::post_mview::dsl::*;
+ use super::post_view::post_fast_view::dsl::*;
use diesel::prelude::*;
- let mut query = post_mview.into_boxed();
+ let mut query = post_fast_view.into_boxed();
query = query.filter(id.eq(from_post_id));
score: 1,
};
+ let read_post_listings_with_user = PostQueryBuilder::create(&conn)
+ .listing_type(ListingType::Community)
+ .sort(&SortType::New)
+ .for_community_id(inserted_community.id)
+ .my_user_id(inserted_user.id)
+ .list()
+ .unwrap();
+
+ let read_post_listings_no_user = PostQueryBuilder::create(&conn)
+ .listing_type(ListingType::Community)
+ .sort(&SortType::New)
+ .for_community_id(inserted_community.id)
+ .list()
+ .unwrap();
+
+ let read_post_listing_no_user = PostView::read(&conn, inserted_post.id, None).unwrap();
+ let read_post_listing_with_user =
+ PostView::read(&conn, inserted_post.id, Some(inserted_user.id)).unwrap();
+
// the non user version
let expected_post_listing_no_user = PostView {
user_id: None,
score: 1,
upvotes: 1,
downvotes: 0,
- hot_rank: 1728,
+ hot_rank: read_post_listing_no_user.hot_rank,
published: inserted_post.published,
newest_activity_time: inserted_post.published,
updated: None,
score: 1,
upvotes: 1,
downvotes: 0,
- hot_rank: 1728,
+ hot_rank: read_post_listing_with_user.hot_rank,
published: inserted_post.published,
newest_activity_time: inserted_post.published,
updated: None,
- subscribed: None,
- read: None,
- saved: None,
+ subscribed: Some(false),
+ read: Some(false),
+ saved: Some(false),
nsfw: false,
embed_title: None,
embed_description: None,
community_local: true,
};
- let read_post_listings_with_user = PostQueryBuilder::create(&conn)
- .listing_type(ListingType::Community)
- .sort(&SortType::New)
- .for_community_id(inserted_community.id)
- .my_user_id(inserted_user.id)
- .list()
- .unwrap();
-
- let read_post_listings_no_user = PostQueryBuilder::create(&conn)
- .listing_type(ListingType::Community)
- .sort(&SortType::New)
- .for_community_id(inserted_community.id)
- .list()
- .unwrap();
-
- let read_post_listing_no_user = PostView::read(&conn, inserted_post.id, None).unwrap();
- let read_post_listing_with_user =
- PostView::read(&conn, inserted_post.id, Some(inserted_user.id)).unwrap();
-
let like_removed = PostLike::remove(&conn, &post_like_form).unwrap();
let num_deleted = Post::delete(&conn, inserted_post.id).unwrap();
Community::delete(&conn, inserted_community.id).unwrap();
}
}
-table! {
- private_message_mview (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,
- }
-}
-
#[derive(
Queryable, Identifiable, PartialEq, Debug, Serialize, Deserialize, QueryableByName, Clone,
)]
pub struct PrivateMessageQueryBuilder<'a> {
conn: &'a PgConnection,
- query: super::private_message_view::private_message_mview::BoxedQuery<'a, Pg>,
+ query: super::private_message_view::private_message_view::BoxedQuery<'a, Pg>,
for_recipient_id: i32,
unread_only: bool,
page: Option<i64>,
impl<'a> PrivateMessageQueryBuilder<'a> {
pub fn create(conn: &'a PgConnection, for_recipient_id: i32) -> Self {
- use super::private_message_view::private_message_mview::dsl::*;
+ use super::private_message_view::private_message_view::dsl::*;
- let query = private_message_mview.into_boxed();
+ let query = private_message_view.into_boxed();
PrivateMessageQueryBuilder {
conn,
}
pub fn list(self) -> Result<Vec<PrivateMessageView>, Error> {
- use super::private_message_view::private_message_mview::dsl::*;
+ use super::private_message_view::private_message_view::dsl::*;
let mut query = self.query.filter(deleted.eq(false));
}
table! {
- user_mention_mview (id) {
+ user_mention_fast_view (id) {
id -> Int4,
user_mention_id -> Int4,
creator_id -> Int4,
#[derive(
Queryable, Identifiable, PartialEq, Debug, Serialize, Deserialize, QueryableByName, Clone,
)]
-#[table_name = "user_mention_view"]
+#[table_name = "user_mention_fast_view"]
pub struct UserMentionView {
pub id: i32,
pub user_mention_id: i32,
pub struct UserMentionQueryBuilder<'a> {
conn: &'a PgConnection,
- query: super::user_mention_view::user_mention_mview::BoxedQuery<'a, Pg>,
+ query: super::user_mention_view::user_mention_fast_view::BoxedQuery<'a, Pg>,
for_user_id: i32,
sort: &'a SortType,
unread_only: bool,
impl<'a> UserMentionQueryBuilder<'a> {
pub fn create(conn: &'a PgConnection, for_user_id: i32) -> Self {
- use super::user_mention_view::user_mention_mview::dsl::*;
+ use super::user_mention_view::user_mention_fast_view::dsl::*;
- let query = user_mention_mview.into_boxed();
+ let query = user_mention_fast_view.into_boxed();
UserMentionQueryBuilder {
conn,
}
pub fn list(self) -> Result<Vec<UserMentionView>, Error> {
- use super::user_mention_view::user_mention_mview::dsl::*;
+ use super::user_mention_view::user_mention_fast_view::dsl::*;
let mut query = self.query;
from_user_mention_id: i32,
from_recipient_id: i32,
) -> Result<Self, Error> {
- use super::user_mention_view::user_mention_view::dsl::*;
+ use super::user_mention_view::user_mention_fast_view::dsl::*;
- user_mention_view
+ user_mention_fast_view
.filter(user_mention_id.eq(from_user_mention_id))
.filter(user_id.eq(from_recipient_id))
.first::<Self>(conn)
-use super::user_view::user_mview::BoxedQuery;
+use super::user_view::user_fast::BoxedQuery;
use crate::db::{fuzzy_search, limit_and_offset, MaybeOptional, SortType};
use diesel::{dsl::*, pg::Pg, result::Error, *};
use serde::{Deserialize, Serialize};
}
table! {
- user_mview (id) {
+ user_fast (id) {
id -> Int4,
actor_id -> Text,
name -> Varchar,
#[derive(
Queryable, Identifiable, PartialEq, Debug, Serialize, Deserialize, QueryableByName, Clone,
)]
-#[table_name = "user_view"]
+#[table_name = "user_fast"]
pub struct UserView {
pub id: i32,
pub actor_id: String,
impl<'a> UserQueryBuilder<'a> {
pub fn create(conn: &'a PgConnection) -> Self {
- use super::user_view::user_mview::dsl::*;
+ use super::user_view::user_fast::dsl::*;
- let query = user_mview.into_boxed();
+ let query = user_fast.into_boxed();
UserQueryBuilder {
conn,
}
pub fn search_term<T: MaybeOptional<String>>(mut self, search_term: T) -> Self {
- use super::user_view::user_mview::dsl::*;
+ use super::user_view::user_fast::dsl::*;
if let Some(search_term) = search_term.get_optional() {
self.query = self.query.filter(name.ilike(fuzzy_search(&search_term)));
}
}
pub fn list(self) -> Result<Vec<UserView>, Error> {
- use super::user_view::user_mview::dsl::*;
+ use super::user_view::user_fast::dsl::*;
let mut query = self.query;
impl UserView {
pub fn read(conn: &PgConnection, from_user_id: i32) -> Result<Self, Error> {
- use super::user_view::user_mview::dsl::*;
- user_mview.find(from_user_id).first::<Self>(conn)
+ use super::user_view::user_fast::dsl::*;
+ user_fast.find(from_user_id).first::<Self>(conn)
}
pub fn admins(conn: &PgConnection) -> Result<Vec<Self>, Error> {
- use super::user_view::user_mview::dsl::*;
- user_mview.filter(admin.eq(true)).load::<Self>(conn)
+ use super::user_view::user_fast::dsl::*;
+ user_fast.filter(admin.eq(true)).load::<Self>(conn)
}
pub fn banned(conn: &PgConnection) -> Result<Vec<Self>, Error> {
- use super::user_view::user_mview::dsl::*;
- user_mview.filter(banned.eq(true)).load::<Self>(conn)
+ use super::user_view::user_fast::dsl::*;
+ user_fast.filter(banned.eq(true)).load::<Self>(conn)
}
}
}
}
+table! {
+ comment_aggregates_fast (id) {
+ id -> Int4,
+ creator_id -> Nullable<Int4>,
+ post_id -> Nullable<Int4>,
+ parent_id -> Nullable<Int4>,
+ content -> Nullable<Text>,
+ removed -> Nullable<Bool>,
+ read -> Nullable<Bool>,
+ published -> Nullable<Timestamp>,
+ updated -> Nullable<Timestamp>,
+ deleted -> Nullable<Bool>,
+ ap_id -> Nullable<Varchar>,
+ local -> Nullable<Bool>,
+ community_id -> Nullable<Int4>,
+ community_actor_id -> Nullable<Varchar>,
+ community_local -> Nullable<Bool>,
+ community_name -> Nullable<Varchar>,
+ banned -> Nullable<Bool>,
+ banned_from_community -> Nullable<Bool>,
+ creator_actor_id -> Nullable<Varchar>,
+ creator_local -> Nullable<Bool>,
+ creator_name -> Nullable<Varchar>,
+ creator_avatar -> Nullable<Text>,
+ score -> Nullable<Int8>,
+ upvotes -> Nullable<Int8>,
+ downvotes -> Nullable<Int8>,
+ hot_rank -> Nullable<Int4>,
+ }
+}
+
table! {
comment_like (id) {
id -> Int4,
}
}
+table! {
+ community_aggregates_fast (id) {
+ id -> Int4,
+ name -> Nullable<Varchar>,
+ title -> Nullable<Varchar>,
+ description -> Nullable<Text>,
+ category_id -> Nullable<Int4>,
+ creator_id -> Nullable<Int4>,
+ removed -> Nullable<Bool>,
+ published -> Nullable<Timestamp>,
+ updated -> Nullable<Timestamp>,
+ deleted -> Nullable<Bool>,
+ nsfw -> Nullable<Bool>,
+ actor_id -> Nullable<Varchar>,
+ local -> Nullable<Bool>,
+ last_refreshed_at -> Nullable<Timestamp>,
+ creator_actor_id -> Nullable<Varchar>,
+ creator_local -> Nullable<Bool>,
+ creator_name -> Nullable<Varchar>,
+ creator_avatar -> Nullable<Text>,
+ category_name -> Nullable<Varchar>,
+ number_of_subscribers -> Nullable<Int8>,
+ number_of_posts -> Nullable<Int8>,
+ number_of_comments -> Nullable<Int8>,
+ hot_rank -> Nullable<Int4>,
+ }
+}
+
table! {
community_follower (id) {
id -> Int4,
}
}
+table! {
+ post_aggregates_fast (id) {
+ id -> Int4,
+ name -> Nullable<Varchar>,
+ url -> Nullable<Text>,
+ body -> Nullable<Text>,
+ creator_id -> Nullable<Int4>,
+ community_id -> Nullable<Int4>,
+ removed -> Nullable<Bool>,
+ locked -> Nullable<Bool>,
+ published -> Nullable<Timestamp>,
+ updated -> Nullable<Timestamp>,
+ deleted -> Nullable<Bool>,
+ nsfw -> Nullable<Bool>,
+ stickied -> Nullable<Bool>,
+ embed_title -> Nullable<Text>,
+ embed_description -> Nullable<Text>,
+ embed_html -> Nullable<Text>,
+ thumbnail_url -> Nullable<Text>,
+ ap_id -> Nullable<Varchar>,
+ local -> Nullable<Bool>,
+ creator_actor_id -> Nullable<Varchar>,
+ creator_local -> Nullable<Bool>,
+ creator_name -> Nullable<Varchar>,
+ creator_avatar -> Nullable<Text>,
+ banned -> Nullable<Bool>,
+ banned_from_community -> Nullable<Bool>,
+ community_actor_id -> Nullable<Varchar>,
+ community_local -> Nullable<Bool>,
+ community_name -> Nullable<Varchar>,
+ community_removed -> Nullable<Bool>,
+ community_deleted -> Nullable<Bool>,
+ community_nsfw -> Nullable<Bool>,
+ number_of_comments -> Nullable<Int8>,
+ score -> Nullable<Int8>,
+ upvotes -> Nullable<Int8>,
+ downvotes -> Nullable<Int8>,
+ hot_rank -> Nullable<Int4>,
+ newest_activity_time -> Nullable<Timestamp>,
+ }
+}
+
table! {
post_like (id) {
id -> Int4,
}
}
+table! {
+ user_fast (id) {
+ id -> Int4,
+ actor_id -> Nullable<Varchar>,
+ name -> Nullable<Varchar>,
+ avatar -> Nullable<Text>,
+ email -> Nullable<Text>,
+ matrix_user_id -> Nullable<Text>,
+ bio -> Nullable<Text>,
+ local -> Nullable<Bool>,
+ admin -> Nullable<Bool>,
+ banned -> Nullable<Bool>,
+ show_avatars -> Nullable<Bool>,
+ send_notifications_to_email -> Nullable<Bool>,
+ published -> Nullable<Timestamp>,
+ number_of_posts -> Nullable<Int8>,
+ post_score -> Nullable<Int8>,
+ number_of_comments -> Nullable<Int8>,
+ comment_score -> Nullable<Int8>,
+ }
+}
+
table! {
user_mention (id) {
id -> Int4,
activity,
category,
comment,
+ comment_aggregates_fast,
comment_like,
comment_saved,
community,
+ community_aggregates_fast,
community_follower,
community_moderator,
community_user_ban,
mod_sticky_post,
password_reset_request,
post,
+ post_aggregates_fast,
post_like,
post_read,
post_saved,
site,
user_,
user_ban,
+ user_fast,
user_mention,
);
+a.removed - +b.removed ||
+a.deleted - +b.deleted ||
(communityType && +b.stickied - +a.stickied) ||
- hotRankPost(b) - hotRankPost(a)
+ b.hot_rank - a.hot_rank
);
}
}