From a4428528e30b18eb85596edf9c26bc8b6b7d11ee Mon Sep 17 00:00:00 2001 From: Dessalines Date: Sun, 29 Dec 2019 15:39:48 -0500 Subject: Adding user avatars / icons. Requires pictshare. - Fixes #188 --- .../2019-12-29-164820_add_avatar/down.sql | 224 ++++++++++++++++++++ .../migrations/2019-12-29-164820_add_avatar/up.sql | 234 +++++++++++++++++++++ 2 files changed, 458 insertions(+) create mode 100644 server/migrations/2019-12-29-164820_add_avatar/down.sql create mode 100644 server/migrations/2019-12-29-164820_add_avatar/up.sql (limited to 'server/migrations') diff --git a/server/migrations/2019-12-29-164820_add_avatar/down.sql b/server/migrations/2019-12-29-164820_add_avatar/down.sql new file mode 100644 index 00000000..74b4146d --- /dev/null +++ b/server/migrations/2019-12-29-164820_add_avatar/down.sql @@ -0,0 +1,224 @@ +-- the views +drop view user_mention_view; +drop view reply_view; +drop view comment_view; +drop view user_view; + +-- user +create view user_view as +select id, +name, +fedi_name, +admin, +banned, +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; + +-- 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 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 +; + +-- community + +drop 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 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 +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, + 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.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; + +-- community tables +drop view community_moderator_view; +drop view community_follower_view; +drop view community_user_ban_view; +drop view site_view; + +create view community_moderator_view as +select *, +(select name from user_ u where cm.user_id = u.id) as user_name, +(select name from community c where cm.community_id = c.id) as community_name +from community_moderator cm; + +create view community_follower_view as +select *, +(select name from user_ u where cf.user_id = u.id) as user_name, +(select name from community c where cf.community_id = c.id) as community_name +from community_follower cf; + +create view community_user_ban_view as +select *, +(select name from user_ u where cm.user_id = u.id) as user_name, +(select name from community c where cm.community_id = c.id) as community_name +from community_user_ban cm; + +create view site_view as +select *, +(select name from user_ u where s.creator_id = u.id) as creator_name, +(select count(*) from user_) as number_of_users, +(select count(*) from post) as number_of_posts, +(select count(*) from comment) as number_of_comments, +(select count(*) from community) as number_of_communities +from site s; + +alter table user_ rename column avatar to icon; +alter table user_ alter column icon type bytea using icon::bytea; diff --git a/server/migrations/2019-12-29-164820_add_avatar/up.sql b/server/migrations/2019-12-29-164820_add_avatar/up.sql new file mode 100644 index 00000000..f9265154 --- /dev/null +++ b/server/migrations/2019-12-29-164820_add_avatar/up.sql @@ -0,0 +1,234 @@ +-- Rename to avatar +alter table user_ rename column icon to avatar; +alter table user_ alter column avatar type text; + +-- Rebuild nearly all the views, to include the creator avatars + +-- user +drop view user_view; +create view user_view as +select id, +name, +avatar, +fedi_name, +admin, +banned, +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; + +-- 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 +; + + +-- community +drop 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 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; + +-- community views +drop view community_moderator_view; +drop view community_follower_view; +drop view community_user_ban_view; +drop view site_view; + +create view community_moderator_view as +select *, +(select name from user_ u where cm.user_id = u.id) as user_name, +(select avatar from user_ u where cm.user_id = u.id), +(select name from community c where cm.community_id = c.id) as community_name +from community_moderator cm; + +create view community_follower_view as +select *, +(select name from user_ u where cf.user_id = u.id) as user_name, +(select avatar from user_ u where cf.user_id = u.id), +(select name from community c where cf.community_id = c.id) as community_name +from community_follower cf; + +create view community_user_ban_view as +select *, +(select name from user_ u where cm.user_id = u.id) as user_name, +(select avatar from user_ u where cm.user_id = u.id), +(select name from community c where cm.community_id = c.id) as community_name +from community_user_ban cm; + +create view site_view as +select *, +(select name from user_ u where s.creator_id = u.id) as creator_name, +(select avatar from user_ u where s.creator_id = u.id) as creator_avatar, +(select count(*) from user_) as number_of_users, +(select count(*) from post) as number_of_posts, +(select count(*) from comment) as number_of_comments, +(select count(*) from community) as number_of_communities +from site s; -- cgit v1.2.3