denormalize ranking metrics

This commit is contained in:
keyan 2022-05-17 14:54:12 -05:00
parent efa267f128
commit 35b533c572
4 changed files with 87 additions and 51 deletions

View File

@ -8,19 +8,15 @@ import { BOOST_MIN } from '../../lib/constants'
async function comments (models, id, sort) {
let orderBy
let join
switch (sort) {
case 'top':
orderBy = 'ORDER BY x.sats DESC NULLS LAST'
join = COMMENTS_LEFT_JOIN_WEIGHTED_SATS
orderBy = 'ORDER BY "Item"."weightedVotes" DESC, "Item".id DESC'
break
case 'recent':
orderBy = 'ORDER BY "Item".created_at DESC'
join = ''
orderBy = 'ORDER BY "Item".created_at DESC, "Item".id DESC'
break
default:
orderBy = COMMENTS_ORDER_BY_SATS
join = COMMENTS_LEFT_JOIN_WEIGHTED_SATS
break
}
@ -28,28 +24,17 @@ async function comments (models, id, sort) {
WITH RECURSIVE base AS (
${SELECT}, ARRAY[row_number() OVER (${orderBy}, "Item".path)] AS sort_path
FROM "Item"
${join}
WHERE "parentId" = $1
UNION ALL
${SELECT}, p.sort_path || row_number() OVER (${orderBy}, "Item".path)
FROM base p
JOIN "Item" ON "Item"."parentId" = p.id
${join})
JOIN "Item" ON "Item"."parentId" = p.id)
SELECT * FROM base ORDER BY sort_path`, Number(id))
return nestComments(flat, id)[0]
}
const COMMENTS_LEFT_JOIN_WEIGHTED_SATS_SELECT = 'SELECT "Item".id, SUM(CASE WHEN "ItemAct".act = \'VOTE\' AND "Item"."userId" <> "ItemAct"."userId" THEN users.trust ELSE 0 END) as sats'
const COMMENTS_LEFT_JOIN_WEIGHTED_SATS =
`LEFT JOIN LATERAL (
${COMMENTS_LEFT_JOIN_WEIGHTED_SATS_SELECT}
FROM "ItemAct"
JOIN users on "ItemAct"."userId" = users.id
WHERE "Item".id = "ItemAct"."itemId" AND "ItemAct".act = 'VOTE'
GROUP BY "Item".id
) x ON "Item".id = x.id`
const COMMENTS_ORDER_BY_SATS =
'ORDER BY GREATEST(x.sats, 0)/POWER(EXTRACT(EPOCH FROM ((NOW() AT TIME ZONE \'UTC\') - "Item".created_at))/3600+2, 1.3) DESC NULLS LAST, "Item".id DESC'
'ORDER BY "Item"."weightedVotes"/POWER(EXTRACT(EPOCH FROM ((NOW() AT TIME ZONE \'UTC\') - "Item".created_at))/3600+2, 1.3) DESC NULLS LAST, "Item".id DESC'
export async function getItem (parent, { id }, { models }) {
const [item] = await models.$queryRaw(`
@ -131,7 +116,6 @@ export default {
items = await models.$queryRaw(`
${SELECT}
FROM "Item"
${newTimedLeftJoinWeightedSats(1)}
WHERE "parentId" IS NULL AND "Item".created_at <= $1
AND "pinId" IS NULL
${topClause(within)}
@ -172,7 +156,6 @@ export default {
items = await models.$queryRaw(`
${SELECT}
FROM "Item"
${newTimedLeftJoinWeightedSats(1)}
WHERE "parentId" IS NULL AND "Item".created_at <= $1 AND "Item".created_at > $3
AND "pinId" IS NULL
${subClause(4)}
@ -185,7 +168,6 @@ export default {
items = await models.$queryRaw(`
${SELECT}
FROM "Item"
${newTimedLeftJoinWeightedSats(1)}
WHERE "parentId" IS NULL AND "Item".created_at <= $1
AND "pinId" IS NULL
${subClause(3)}
@ -258,7 +240,6 @@ export default {
comments = await models.$queryRaw(`
${SELECT}
FROM "Item"
${newTimedLeftJoinWeightedSats(1)}
WHERE "parentId" IS NOT NULL
AND "Item".created_at <= $1
${topClause(within)}
@ -858,17 +839,10 @@ export const SELECT =
"Item".company, "Item".location, "Item".remote,
"Item"."subName", "Item".status, ltree2text("Item"."path") AS "path"`
function newTimedLeftJoinWeightedSats (num) {
return `
LEFT JOIN "ItemAct" ON "Item".id = "ItemAct"."itemId" AND "ItemAct".created_at <= $${num} AND "ItemAct".act IN ('VOTE', 'BOOST')
JOIN users ON "ItemAct"."userId" = users.id`
}
function newTimedOrderByWeightedSats (num) {
return `
GROUP BY "Item".id
ORDER BY (SUM(CASE WHEN "ItemAct".act = 'VOTE' AND "Item"."userId" <> "ItemAct"."userId" THEN users.trust ELSE 0 END)/POWER(EXTRACT(EPOCH FROM ($${num} - "Item".created_at))/3600+2, 1.3) +
GREATEST(SUM(CASE WHEN "ItemAct".act = 'BOOST' THEN "ItemAct".sats ELSE 0 END)-1000+5, 0)/POWER(EXTRACT(EPOCH FROM ($${num} - "Item".created_at))/3600+2, 4)) DESC NULLS LAST, "Item".id DESC`
ORDER BY ("Item"."weightedVotes"/POWER(EXTRACT(EPOCH FROM ($${num} - "Item".created_at))/3600+2, 1.3) +
GREATEST("Item".boost-1000+5, 0)/POWER(EXTRACT(EPOCH FROM ($${num} - "Item".created_at))/3600+2, 4)) DESC NULLS LAST, "Item".id DESC`
}
const TOP_ORDER_BY_SATS = 'GROUP BY "Item".id ORDER BY (SUM(CASE WHEN "ItemAct".act = \'VOTE\' AND "Item"."userId" <> "ItemAct"."userId" THEN users.trust ELSE 0 END)) DESC NULLS LAST, "Item".created_at DESC'
const TOP_ORDER_BY_SATS = 'ORDER BY "Item"."weightedVotes" DESC NULLS LAST, "Item".id DESC'

View File

@ -0,0 +1,34 @@
-- AlterTable
ALTER TABLE "Item" ADD COLUMN "weightedVotes" DOUBLE PRECISION NOT NULL DEFAULT 0;
-- loop over all existing votes and denormalize them
UPDATE "Item"
SET "weightedVotes" = subquery.votes
FROM (SELECT "ItemAct"."itemId", SUM(users.trust) AS votes
FROM "ItemAct"
JOIN users ON "ItemAct"."userId" = users.id
JOIN "Item" ON "Item".id = "ItemAct"."itemId"
WHERE "ItemAct".act = 'VOTE' AND "Item"."userId" <> "ItemAct"."userId"
GROUP BY "ItemAct"."itemId") subquery
WHERE "Item".id = subquery."itemId";
CREATE OR REPLACE FUNCTION weighted_votes_after_act() RETURNS TRIGGER AS $$
DECLARE
user_trust DOUBLE PRECISION;
BEGIN
-- grab user's trust who is upvoting
SELECT trust INTO user_trust FROM users WHERE id = NEW."userId";
-- update item
UPDATE "Item"
SET "weightedVotes" = "weightedVotes" + user_trust
WHERE id = NEW."itemId" AND "userId" <> NEW."userId";
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS weighted_votes_after_act ON "ItemAct";
CREATE TRIGGER weighted_votes_after_act
AFTER INSERT ON "ItemAct"
FOR EACH ROW
WHEN (NEW.act = 'VOTE')
EXECUTE PROCEDURE weighted_votes_after_act();

View File

@ -0,0 +1,26 @@
-- AlterTable
ALTER TABLE "Item" ADD COLUMN "boost" INTEGER NOT NULL DEFAULT 0;
-- loop over all existing votes and denormalize them
UPDATE "Item"
SET boost = subquery.boost
FROM (SELECT "ItemAct"."itemId", SUM("ItemAct".sats) AS boost
FROM "ItemAct"
WHERE "ItemAct".act = 'BOOST'
GROUP BY "ItemAct"."itemId") subquery
WHERE "Item".id = subquery."itemId";
CREATE OR REPLACE FUNCTION boost_after_act() RETURNS TRIGGER AS $$
BEGIN
-- update item
UPDATE "Item" SET boost = boost + NEW.sats WHERE id = NEW."itemId";
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS boost_after_act ON "ItemAct";
CREATE TRIGGER boost_after_act
AFTER INSERT ON "ItemAct"
FOR EACH ROW
WHEN (NEW.act = 'BOOST')
EXECUTE PROCEDURE boost_after_act();

View File

@ -140,24 +140,26 @@ enum Status {
}
model Item {
id Int @id @default(autoincrement())
createdAt DateTime @default(now()) @map(name: "created_at")
updatedAt DateTime @default(now()) @updatedAt @map(name: "updated_at")
title String?
text String?
url String?
user User @relation("UserItems", fields: [userId], references: [id])
userId Int
fwdUser User? @relation(name: "FwdItem", fields: [fwdUserId], references: [id])
fwdUserId Int?
parent Item? @relation("ParentChildren", fields: [parentId], references: [id])
parentId Int?
children Item[] @relation("ParentChildren")
actions ItemAct[]
mentions Mention[]
path Unsupported("LTREE")?
pin Pin? @relation(fields: [pinId], references: [id])
pinId Int?
id Int @id @default(autoincrement())
createdAt DateTime @default(now()) @map(name: "created_at")
updatedAt DateTime @default(now()) @updatedAt @map(name: "updated_at")
title String?
text String?
url String?
user User @relation("UserItems", fields: [userId], references: [id])
userId Int
fwdUser User? @relation(name: "FwdItem", fields: [fwdUserId], references: [id])
fwdUserId Int?
parent Item? @relation("ParentChildren", fields: [parentId], references: [id])
parentId Int?
children Item[] @relation("ParentChildren")
actions ItemAct[]
mentions Mention[]
path Unsupported("LTREE")?
pin Pin? @relation(fields: [pinId], references: [id])
pinId Int?
weightedVotes Float @default(0)
boost Int @default(0)
// if sub is null, this is the main sub
sub Sub? @relation(fields: [subName], references: [name])