Starting to add post_view.

This commit is contained in:
Dessalines 2020-12-10 15:53:49 -05:00
parent dabcfca67b
commit eef93440d0
9 changed files with 980 additions and 5 deletions

View file

@ -1,3 +1,4 @@
pub mod community_aggregates;
pub mod post_aggregates;
pub mod site_aggregates;
pub mod user_aggregates;

View file

@ -0,0 +1,268 @@
use crate::schema::post_aggregates;
use diesel::{result::Error, *};
use serde::Serialize;
#[derive(Queryable, Associations, Identifiable, PartialEq, Debug, Serialize, Clone)]
#[table_name = "post_aggregates"]
pub struct PostAggregates {
pub id: i32,
pub post_id: i32,
pub comments: i64,
pub score: i64,
pub upvotes: i64,
pub downvotes: i64,
pub newest_comment_time: chrono::NaiveDateTime,
}
impl PostAggregates {
pub fn read(conn: &PgConnection, post_id: i32) -> Result<Self, Error> {
post_aggregates::table
.filter(post_aggregates::post_id.eq(post_id))
.first::<Self>(conn)
}
}
// #[cfg(test)]
// mod tests {
// use crate::{
// aggregates::community_aggregates::CommunityAggregates,
// comment::{Comment, CommentForm},
// community::{Community, CommunityFollower, CommunityFollowerForm, CommunityForm},
// post::{Post, PostForm},
// tests::establish_unpooled_connection,
// user::{UserForm, User_},
// Crud,
// Followable,
// ListingType,
// SortType,
// };
// #[test]
// fn test_crud() {
// let conn = establish_unpooled_connection();
// let new_user = UserForm {
// name: "thommy_community_agg".into(),
// preferred_username: None,
// password_encrypted: "nope".into(),
// email: None,
// matrix_user_id: None,
// avatar: None,
// banner: None,
// admin: false,
// banned: Some(false),
// published: None,
// updated: None,
// show_nsfw: false,
// theme: "browser".into(),
// default_sort_type: SortType::Hot as i16,
// default_listing_type: ListingType::Subscribed as i16,
// lang: "browser".into(),
// show_avatars: true,
// send_notifications_to_email: false,
// actor_id: None,
// bio: None,
// local: true,
// private_key: None,
// public_key: None,
// last_refreshed_at: None,
// };
// let inserted_user = User_::create(&conn, &new_user).unwrap();
// let another_user = UserForm {
// name: "jerry_community_agg".into(),
// preferred_username: None,
// password_encrypted: "nope".into(),
// email: None,
// matrix_user_id: None,
// avatar: None,
// banner: None,
// admin: false,
// banned: Some(false),
// published: None,
// updated: None,
// show_nsfw: false,
// theme: "browser".into(),
// default_sort_type: SortType::Hot as i16,
// default_listing_type: ListingType::Subscribed as i16,
// lang: "browser".into(),
// show_avatars: true,
// send_notifications_to_email: false,
// actor_id: None,
// bio: None,
// local: true,
// private_key: None,
// public_key: None,
// last_refreshed_at: None,
// };
// let another_inserted_user = User_::create(&conn, &another_user).unwrap();
// let new_community = CommunityForm {
// name: "TIL_community_agg".into(),
// creator_id: inserted_user.id,
// title: "nada".to_owned(),
// description: None,
// category_id: 1,
// nsfw: false,
// removed: None,
// deleted: None,
// updated: None,
// actor_id: None,
// local: true,
// private_key: None,
// public_key: None,
// last_refreshed_at: None,
// published: None,
// icon: None,
// banner: None,
// };
// let inserted_community = Community::create(&conn, &new_community).unwrap();
// let another_community = CommunityForm {
// name: "TIL_community_agg_2".into(),
// creator_id: inserted_user.id,
// title: "nada".to_owned(),
// description: None,
// category_id: 1,
// nsfw: false,
// removed: None,
// deleted: None,
// updated: None,
// actor_id: None,
// local: true,
// private_key: None,
// public_key: None,
// last_refreshed_at: None,
// published: None,
// icon: None,
// banner: None,
// };
// let another_inserted_community = Community::create(&conn, &another_community).unwrap();
// let first_user_follow = CommunityFollowerForm {
// community_id: inserted_community.id,
// user_id: inserted_user.id,
// pending: false,
// };
// CommunityFollower::follow(&conn, &first_user_follow).unwrap();
// let second_user_follow = CommunityFollowerForm {
// community_id: inserted_community.id,
// user_id: another_inserted_user.id,
// pending: false,
// };
// CommunityFollower::follow(&conn, &second_user_follow).unwrap();
// let another_community_follow = CommunityFollowerForm {
// community_id: another_inserted_community.id,
// user_id: inserted_user.id,
// pending: false,
// };
// CommunityFollower::follow(&conn, &another_community_follow).unwrap();
// let new_post = PostForm {
// name: "A test post".into(),
// url: None,
// body: None,
// creator_id: inserted_user.id,
// community_id: inserted_community.id,
// removed: None,
// deleted: None,
// locked: None,
// stickied: None,
// nsfw: false,
// updated: None,
// embed_title: None,
// embed_description: None,
// embed_html: None,
// thumbnail_url: None,
// ap_id: None,
// local: true,
// published: None,
// };
// let inserted_post = Post::create(&conn, &new_post).unwrap();
// let comment_form = CommentForm {
// content: "A test comment".into(),
// creator_id: inserted_user.id,
// post_id: inserted_post.id,
// removed: None,
// deleted: None,
// read: None,
// parent_id: None,
// published: None,
// updated: None,
// ap_id: None,
// local: true,
// };
// let inserted_comment = Comment::create(&conn, &comment_form).unwrap();
// let child_comment_form = CommentForm {
// content: "A test comment".into(),
// creator_id: inserted_user.id,
// post_id: inserted_post.id,
// removed: None,
// deleted: None,
// read: None,
// parent_id: Some(inserted_comment.id),
// published: None,
// updated: None,
// ap_id: None,
// local: true,
// };
// let _inserted_child_comment = Comment::create(&conn, &child_comment_form).unwrap();
// let community_aggregates_before_delete =
// CommunityAggregates::read(&conn, inserted_community.id).unwrap();
// assert_eq!(2, community_aggregates_before_delete.subscribers);
// assert_eq!(1, community_aggregates_before_delete.posts);
// assert_eq!(2, community_aggregates_before_delete.comments);
// // Test the other community
// let another_community_aggs =
// CommunityAggregates::read(&conn, another_inserted_community.id).unwrap();
// assert_eq!(1, another_community_aggs.subscribers);
// assert_eq!(0, another_community_aggs.posts);
// assert_eq!(0, another_community_aggs.comments);
// // Unfollow test
// CommunityFollower::unfollow(&conn, &second_user_follow).unwrap();
// let after_unfollow = CommunityAggregates::read(&conn, inserted_community.id).unwrap();
// assert_eq!(1, after_unfollow.subscribers);
// // Follow again just for the later tests
// CommunityFollower::follow(&conn, &second_user_follow).unwrap();
// let after_follow_again = CommunityAggregates::read(&conn, inserted_community.id).unwrap();
// assert_eq!(2, after_follow_again.subscribers);
// // Remove a parent comment (the comment count should also be 0)
// Post::delete(&conn, inserted_post.id).unwrap();
// let after_parent_post_delete = CommunityAggregates::read(&conn, inserted_community.id).unwrap();
// assert_eq!(0, after_parent_post_delete.comments);
// assert_eq!(0, after_parent_post_delete.posts);
// // Remove the 2nd user
// User_::delete(&conn, another_inserted_user.id).unwrap();
// let after_user_delete = CommunityAggregates::read(&conn, inserted_community.id).unwrap();
// assert_eq!(1, after_user_delete.subscribers);
// // This should delete all the associated rows, and fire triggers
// let user_num_deleted = User_::delete(&conn, inserted_user.id).unwrap();
// assert_eq!(1, user_num_deleted);
// // Should be none found, since the creator was deleted
// let after_delete = CommunityAggregates::read(&conn, inserted_community.id);
// assert!(after_delete.is_err());
// }
// }

View file

@ -8,9 +8,10 @@ use crate::{
Saveable,
};
use diesel::{dsl::*, result::Error, *};
use serde::Serialize;
use url::{ParseError, Url};
#[derive(Queryable, Identifiable, PartialEq, Debug)]
#[derive(Clone, Queryable, Identifiable, PartialEq, Debug, Serialize)]
#[table_name = "post"]
pub struct Post {
pub id: i32,

View file

@ -329,6 +329,18 @@ table! {
}
}
table! {
post_aggregates (id) {
id -> Int4,
post_id -> Int4,
comments -> Int8,
score -> Int8,
upvotes -> Int8,
downvotes -> Int8,
newest_comment_time -> Timestamp,
}
}
table! {
post_aggregates_fast (id) {
id -> Int4,
@ -576,6 +588,7 @@ joinable!(mod_sticky_post -> user_ (mod_user_id));
joinable!(password_reset_request -> user_ (user_id));
joinable!(post -> community (community_id));
joinable!(post -> user_ (creator_id));
joinable!(post_aggregates -> post (post_id));
joinable!(post_like -> post (post_id));
joinable!(post_like -> user_ (user_id));
joinable!(post_read -> post (post_id));
@ -614,6 +627,7 @@ allow_tables_to_appear_in_same_query!(
mod_sticky_post,
password_reset_request,
post,
post_aggregates,
post_aggregates_fast,
post_like,
post_read,

View file

@ -32,7 +32,7 @@ impl CommunityView {
// The left join below will return None in this case
let user_id_join = my_user_id.unwrap_or(-1);
let (community, creator, category, counts, subscribed) = community::table
let (community, creator, category, counts, follower) = community::table
.find(community_id)
.inner_join(user_::table)
.inner_join(category::table)
@ -63,7 +63,7 @@ impl CommunityView {
community,
creator,
category,
subscribed: subscribed.is_some(),
subscribed: follower.is_some(),
counts,
})
}

View file

@ -2,7 +2,6 @@ pub mod community_follower_view;
pub mod community_moderator_view;
pub mod community_user_ban_view;
pub mod community_view;
pub mod post_view;
pub mod site_view;
pub mod user_view;
// TODO Every single aggregate trigger is likely broken, you need to test every one of these out

View file

@ -0,0 +1,576 @@
use crate::{
aggregates::post_aggregates::PostAggregates,
community::{Community, CommunityFollower, CommunitySafe, CommunityUserBan},
functions::hot_rank,
fuzzy_search,
limit_and_offset,
post::{Post, PostRead, PostSaved},
schema::{
community,
community_follower,
community_user_ban,
post,
post_aggregates,
post_like,
post_read,
post_saved,
user_,
},
user::{UserSafe, User_},
ListingType,
MaybeOptional,
SortType,
ToSafe,
};
use diesel::{result::Error, *};
use serde::Serialize;
#[derive(Debug, Serialize, Clone)]
pub struct PostView {
pub post: Post,
pub creator: UserSafe,
pub community: CommunitySafe,
pub counts: PostAggregates,
pub subscribed: bool, // Left join to CommunityFollower
pub banned_from_community: bool, // Left Join to CommunityUserBan
pub saved: bool, // Left join to PostSaved
pub read: bool, // Left join to PostRead
pub my_vote: Option<i16>, // Left join to PostLike
}
type OutputTuple = (
Post,
UserSafe,
CommunitySafe,
PostAggregates,
Option<CommunityFollower>,
Option<CommunityUserBan>,
Option<PostSaved>,
Option<PostRead>,
Option<i16>,
);
impl PostView {
pub fn read(conn: &PgConnection, post_id: i32, my_user_id: Option<i32>) -> Result<Self, Error> {
// The left join below will return None in this case
let user_id_join = my_user_id.unwrap_or(-1);
let (post, creator, community, counts, follower, banned_from_community, saved, read, my_vote) =
post::table
.find(post_id)
.inner_join(user_::table)
.inner_join(community::table)
.inner_join(post_aggregates::table)
.left_join(
community_follower::table.on(
post::community_id
.eq(community_follower::community_id)
.and(community_follower::user_id.eq(user_id_join)),
),
)
.left_join(
community_user_ban::table.on(
post::community_id
.eq(community_user_ban::community_id)
.and(community_user_ban::user_id.eq(user_id_join)),
),
)
.left_join(
post_saved::table.on(
post::id
.eq(post_saved::post_id)
.and(post_saved::user_id.eq(user_id_join)),
),
)
.left_join(
post_read::table.on(
post::id
.eq(post_read::post_id)
.and(post_read::user_id.eq(user_id_join)),
),
)
.left_join(
post_like::table.on(
post::id
.eq(post_like::post_id)
.and(post_like::user_id.eq(user_id_join)),
),
)
.select((
post::all_columns,
User_::safe_columns_tuple(),
Community::safe_columns_tuple(),
post_aggregates::all_columns,
community_follower::all_columns.nullable(),
community_user_ban::all_columns.nullable(),
post_saved::all_columns.nullable(),
post_read::all_columns.nullable(),
post_like::score.nullable(),
))
.first::<OutputTuple>(conn)?;
Ok(PostView {
post,
creator,
community,
counts,
subscribed: follower.is_some(),
banned_from_community: banned_from_community.is_some(),
saved: saved.is_some(),
read: read.is_some(),
my_vote,
})
}
}
mod join_types {
use crate::schema::{
community,
community_follower,
community_user_ban,
post,
post_aggregates,
post_like,
post_read,
post_saved,
user_,
};
use diesel::{
pg::Pg,
query_builder::BoxedSelectStatement,
query_source::joins::{Inner, Join, JoinOn, LeftOuter},
sql_types::*,
};
/// TODO awful, but necessary because of the boxed join
pub(super) type BoxedPostJoin<'a> = BoxedSelectStatement<
'a,
(
(
Integer,
Text,
Nullable<Text>,
Nullable<Text>,
Integer,
Integer,
Bool,
Bool,
Timestamp,
Nullable<Timestamp>,
Bool,
Bool,
Bool,
Nullable<Text>,
Nullable<Text>,
Nullable<Text>,
Nullable<Text>,
Text,
Bool,
),
(
Integer,
Text,
Nullable<Text>,
Nullable<Text>,
Bool,
Bool,
Timestamp,
Nullable<Timestamp>,
Nullable<Text>,
Text,
Nullable<Text>,
Bool,
Nullable<Text>,
Bool,
),
(
Integer,
Text,
Text,
Nullable<Text>,
Integer,
Integer,
Bool,
Timestamp,
Nullable<Timestamp>,
Bool,
Bool,
Text,
Bool,
Nullable<Text>,
Nullable<Text>,
),
(Integer, Integer, BigInt, BigInt, BigInt, BigInt, Timestamp),
Nullable<(Integer, Integer, Integer, Timestamp, Nullable<Bool>)>,
Nullable<(Integer, Integer, Integer, Timestamp)>,
Nullable<(Integer, Integer, Integer, Timestamp)>,
Nullable<(Integer, Integer, Integer, Timestamp)>,
Nullable<SmallInt>,
),
JoinOn<
Join<
JoinOn<
Join<
JoinOn<
Join<
JoinOn<
Join<
JoinOn<
Join<
JoinOn<
Join<
JoinOn<
Join<
JoinOn<
Join<post::table, user_::table, Inner>,
diesel::expression::operators::Eq<
diesel::expression::nullable::Nullable<
post::columns::creator_id,
>,
diesel::expression::nullable::Nullable<user_::columns::id>,
>,
>,
community::table,
Inner,
>,
diesel::expression::operators::Eq<
diesel::expression::nullable::Nullable<post::columns::community_id>,
diesel::expression::nullable::Nullable<community::columns::id>,
>,
>,
post_aggregates::table,
Inner,
>,
diesel::expression::operators::Eq<
diesel::expression::nullable::Nullable<
post_aggregates::columns::post_id,
>,
diesel::expression::nullable::Nullable<post::columns::id>,
>,
>,
community_follower::table,
LeftOuter,
>,
diesel::expression::operators::And<
diesel::expression::operators::Eq<
post::columns::community_id,
community_follower::columns::community_id,
>,
diesel::expression::operators::Eq<
community_follower::columns::user_id,
diesel::expression::bound::Bound<diesel::sql_types::Integer, i32>,
>,
>,
>,
community_user_ban::table,
LeftOuter,
>,
diesel::expression::operators::And<
diesel::expression::operators::Eq<
post::columns::community_id,
community_user_ban::columns::community_id,
>,
diesel::expression::operators::Eq<
community_user_ban::columns::user_id,
diesel::expression::bound::Bound<diesel::sql_types::Integer, i32>,
>,
>,
>,
post_saved::table,
LeftOuter,
>,
diesel::expression::operators::And<
diesel::expression::operators::Eq<post::columns::id, post_saved::columns::post_id>,
diesel::expression::operators::Eq<
post_saved::columns::user_id,
diesel::expression::bound::Bound<diesel::sql_types::Integer, i32>,
>,
>,
>,
post_read::table,
LeftOuter,
>,
diesel::expression::operators::And<
diesel::expression::operators::Eq<post::columns::id, post_read::columns::post_id>,
diesel::expression::operators::Eq<
post_read::columns::user_id,
diesel::expression::bound::Bound<diesel::sql_types::Integer, i32>,
>,
>,
>,
post_like::table,
LeftOuter,
>,
diesel::expression::operators::And<
diesel::expression::operators::Eq<post::columns::id, post_like::columns::post_id>,
diesel::expression::operators::Eq<
post_like::columns::user_id,
diesel::expression::bound::Bound<diesel::sql_types::Integer, i32>,
>,
>,
>,
Pg,
>;
}
pub struct PostQueryBuilder<'a> {
conn: &'a PgConnection,
query: join_types::BoxedPostJoin<'a>,
listing_type: &'a ListingType,
sort: &'a SortType,
for_creator_id: Option<i32>,
for_community_id: Option<i32>,
for_community_name: Option<String>,
search_term: Option<String>,
url_search: Option<String>,
show_nsfw: bool,
saved_only: bool,
unread_only: bool,
page: Option<i64>,
limit: Option<i64>,
}
impl<'a> PostQueryBuilder<'a> {
pub fn create(conn: &'a PgConnection, my_user_id: Option<i32>) -> Self {
// The left join below will return None in this case
let user_id_join = my_user_id.unwrap_or(-1);
let query = post::table
.inner_join(user_::table)
.inner_join(community::table)
.inner_join(post_aggregates::table)
.left_join(
community_follower::table.on(
post::community_id
.eq(community_follower::community_id)
.and(community_follower::user_id.eq(user_id_join)),
),
)
.left_join(
community_user_ban::table.on(
post::community_id
.eq(community_user_ban::community_id)
.and(community_user_ban::user_id.eq(user_id_join)),
),
)
.left_join(
post_saved::table.on(
post::id
.eq(post_saved::post_id)
.and(post_saved::user_id.eq(user_id_join)),
),
)
.left_join(
post_read::table.on(
post::id
.eq(post_read::post_id)
.and(post_read::user_id.eq(user_id_join)),
),
)
.left_join(
post_like::table.on(
post::id
.eq(post_like::post_id)
.and(post_like::user_id.eq(user_id_join)),
),
)
.select((
post::all_columns,
User_::safe_columns_tuple(),
Community::safe_columns_tuple(),
post_aggregates::all_columns,
community_follower::all_columns.nullable(),
community_user_ban::all_columns.nullable(),
post_saved::all_columns.nullable(),
post_read::all_columns.nullable(),
post_like::score.nullable(),
))
.into_boxed();
PostQueryBuilder {
conn,
query,
listing_type: &ListingType::All,
sort: &SortType::Hot,
for_creator_id: None,
for_community_id: None,
for_community_name: None,
search_term: None,
url_search: None,
show_nsfw: true,
saved_only: false,
unread_only: false,
page: None,
limit: None,
}
}
pub fn listing_type(mut self, listing_type: &'a ListingType) -> Self {
self.listing_type = listing_type;
self
}
pub fn sort(mut self, sort: &'a SortType) -> Self {
self.sort = sort;
self
}
pub fn for_community_id<T: MaybeOptional<i32>>(mut self, for_community_id: T) -> Self {
self.for_community_id = for_community_id.get_optional();
self
}
pub fn for_community_name<T: MaybeOptional<String>>(mut self, for_community_name: T) -> Self {
self.for_community_name = for_community_name.get_optional();
self
}
pub fn for_creator_id<T: MaybeOptional<i32>>(mut self, for_creator_id: T) -> Self {
self.for_creator_id = for_creator_id.get_optional();
self
}
pub fn search_term<T: MaybeOptional<String>>(mut self, search_term: T) -> Self {
self.search_term = search_term.get_optional();
self
}
pub fn url_search<T: MaybeOptional<String>>(mut self, url_search: T) -> Self {
self.url_search = url_search.get_optional();
self
}
pub fn show_nsfw(mut self, show_nsfw: bool) -> Self {
self.show_nsfw = show_nsfw;
self
}
pub fn saved_only(mut self, saved_only: bool) -> Self {
self.saved_only = saved_only;
self
}
pub fn page<T: MaybeOptional<i64>>(mut self, page: T) -> Self {
self.page = page.get_optional();
self
}
pub fn limit<T: MaybeOptional<i64>>(mut self, limit: T) -> Self {
self.limit = limit.get_optional();
self
}
pub fn list(self) -> Result<Vec<PostView>, Error> {
use diesel::dsl::*;
let mut query = self.query;
query = match self.listing_type {
ListingType::Subscribed => query.filter(community_follower::user_id.is_not_null()), // TODO could be this: and(community_follower::user_id.eq(user_id_join)),
ListingType::Local => query.filter(community::local.eq(true)),
_ => query,
};
if let Some(for_community_id) = self.for_community_id {
query = query
.filter(post::community_id.eq(for_community_id))
.then_order_by(post::stickied.desc());
}
if let Some(for_community_name) = self.for_community_name {
query = query
.filter(community::name.eq(for_community_name))
.filter(community::local.eq(true))
.then_order_by(post::stickied.desc());
}
if let Some(url_search) = self.url_search {
query = query.filter(post::url.eq(url_search));
}
if let Some(search_term) = self.search_term {
let searcher = fuzzy_search(&search_term);
query = query.filter(
post::name
.ilike(searcher.to_owned())
.or(post::body.ilike(searcher)),
);
}
query = match self.sort {
SortType::Active => query
.then_order_by(
hot_rank(post_aggregates::score, post_aggregates::newest_comment_time).desc(),
)
.then_order_by(post::published.desc()),
SortType::Hot => query
.then_order_by(hot_rank(post_aggregates::score, post::published).desc())
.then_order_by(post::published.desc()),
SortType::New => query.then_order_by(post::published.desc()),
SortType::TopAll => query.then_order_by(post_aggregates::score.desc()),
SortType::TopYear => query
.filter(post::published.gt(now - 1.years()))
.then_order_by(post_aggregates::score.desc()),
SortType::TopMonth => query
.filter(post::published.gt(now - 1.months()))
.then_order_by(post_aggregates::score.desc()),
SortType::TopWeek => query
.filter(post::published.gt(now - 1.weeks()))
.then_order_by(post_aggregates::score.desc()),
SortType::TopDay => query
.filter(post::published.gt(now - 1.days()))
.then_order_by(post_aggregates::score.desc()),
};
// If its for a specific user, show the removed / deleted
if let Some(for_creator_id) = self.for_creator_id {
query = query.filter(post::creator_id.eq(for_creator_id));
}
if !self.show_nsfw {
query = query
.filter(post::nsfw.eq(false))
.filter(community::nsfw.eq(false));
};
// TODO These two might be wrong
if self.saved_only {
query = query.filter(post_saved::id.is_not_null());
};
if self.unread_only {
query = query.filter(post_read::id.is_not_null());
};
let (limit, offset) = limit_and_offset(self.page, self.limit);
let res = query
.limit(limit)
.offset(offset)
.filter(post::removed.eq(false))
.filter(post::deleted.eq(false))
.filter(community::removed.eq(false))
.filter(community::deleted.eq(false))
.load::<OutputTuple>(self.conn)?;
Ok(to_vec(res))
}
}
// TODO turn this into a trait with an associated type
fn to_vec(posts: Vec<OutputTuple>) -> Vec<PostView> {
posts
.iter()
.map(|a| PostView {
post: a.0.to_owned(),
creator: a.1.to_owned(),
community: a.2.to_owned(),
counts: a.3.to_owned(),
subscribed: a.4.is_some(),
banned_from_community: a.5.is_some(),
saved: a.6.is_some(),
read: a.7.is_some(),
my_vote: a.8,
})
.collect::<Vec<PostView>>()
}

View file

@ -0,0 +1,9 @@
-- post aggregates
drop table post_aggregates;
drop trigger post_aggregates_post on post;
drop trigger post_aggregates_comment_count on comment;
drop trigger post_aggregates_score on post_like;
drop function
post_aggregates_post,
post_aggregates_comment_count,
post_aggregates_score;

View file

@ -0,0 +1,107 @@
-- Add post aggregates
create table post_aggregates (
id serial primary key,
post_id int references post on update cascade on delete cascade not null,
comments bigint not null default 0,
score bigint not null default 0,
upvotes bigint not null default 0,
downvotes bigint not null default 0,
newest_comment_time timestamp not null default now(),
unique (post_id)
);
insert into post_aggregates (post_id, comments, score, upvotes, downvotes, newest_comment_time)
select
p.id,
coalesce(ct.comments, 0::bigint) as comments,
coalesce(pl.score, 0::bigint) as score,
coalesce(pl.upvotes, 0::bigint) as upvotes,
coalesce(pl.downvotes, 0::bigint) as downvotes,
greatest(ct.recent_comment_time, p.published) as newest_activity_time
from post p
left join (
select comment.post_id,
count(*) as comments,
max(comment.published) as recent_comment_time
from comment
group by comment.post_id
) ct on ct.post_id = p.id
left join (
select post_like.post_id,
sum(post_like.score) as score,
sum(post_like.score) filter (where post_like.score = 1) as upvotes,
-sum(post_like.score) filter (where post_like.score = '-1'::integer) as downvotes
from post_like
group by post_like.post_id
) pl on pl.post_id = p.id;
-- Add community aggregate triggers
-- initial post add
create function post_aggregates_post()
returns trigger language plpgsql
as $$
begin
IF (TG_OP = 'INSERT') THEN
insert into post_aggregates (post_id) values (NEW.id);
ELSIF (TG_OP = 'DELETE') THEN
delete from post_aggregates where post_id = OLD.id;
END IF;
return null;
end $$;
create trigger post_aggregates_post
after insert or delete on post
for each row
execute procedure post_aggregates_post();
-- comment count
create function post_aggregates_comment_count()
returns trigger language plpgsql
as $$
begin
IF (TG_OP = 'INSERT') THEN
update post_aggregates pa
set comments = comments + 1,
newest_comment_time = NEW.published
where pa.post_id = NEW.post_id;
ELSIF (TG_OP = 'DELETE') THEN
update post_aggregates pa
set comments = comments - 1
where pa.post_id = OLD.post_id;
END IF;
return null;
end $$;
create trigger post_aggregates_comment_count
after insert or delete on comment
for each row
execute procedure post_aggregates_comment_count();
-- post score
create function post_aggregates_score()
returns trigger language plpgsql
as $$
begin
IF (TG_OP = 'INSERT') THEN
update post_aggregates pa
set score = score + NEW.score,
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 pa.post_id = NEW.post_id;
ELSIF (TG_OP = 'DELETE') THEN
update post_aggregates pa
set score = score - OLD.score,
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 pa.post_id = OLD.post_id;
END IF;
return null;
end $$;
create trigger post_aggregates_score
after insert or delete on post_like
for each row
execute procedure post_aggregates_score();