-- Rank = ScaleFactor * sign(Score) * log(1 + abs(Score)) / (Time + 2)^Gravity CREATE OR REPLACE FUNCTION hot_rank (score numeric, published timestamp without time zone) RETURNS integer AS $$ BEGIN -- hours_diff:=EXTRACT(EPOCH FROM (timezone('utc',now()) - published))/3600 RETURN floor(10000 * log(greatest (1, score + 3)) / power(((EXTRACT(EPOCH FROM (timezone('utc', now()) - published)) / 3600) + 2), 1.8))::integer; END; $$ LANGUAGE plpgsql; CREATE VIEW post_view AS with all_post AS ( SELECT p.*, ( 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 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;