denormalize votes

This commit is contained in:
keyan 2023-05-06 18:53:10 -05:00
parent e2aceee234
commit 1c608d42f4
4 changed files with 47 additions and 10 deletions

View File

@ -904,14 +904,6 @@ export default {
}
return comments(me, models, item.id, item.pinId ? 'recent' : 'hot', item)
},
upvotes: async (item, args, { models }) => {
const [{ count }] = await models.$queryRaw(`
SELECT COUNT(DISTINCT "userId") as count
FROM "ItemAct"
WHERE act = 'TIP' AND "itemId" = $1`, Number(item.id))
return count
},
wvotes: async (item) => {
return item.weightedVotes - item.weightedDownVotes
},
@ -1123,7 +1115,7 @@ const createItem = async (parent, { sub, title, url, text, boost, forward, bount
export const SELECT =
`SELECT "Item".id, "Item".created_at as "createdAt", "Item".updated_at as "updatedAt", "Item".title,
"Item".text, "Item".url, "Item"."bounty", "Item"."userId", "Item"."fwdUserId", "Item"."parentId",
"Item"."pinId", "Item"."maxBid", "Item"."rootId",
"Item"."pinId", "Item"."maxBid", "Item"."rootId", "Item".upvotes,
"Item".company, "Item".location, "Item".remote, "Item"."deletedAt",
"Item"."subName", "Item".status, "Item"."uploadId", "Item"."pollCost", "Item".boost,
"Item".msats, "Item".ncomments, "Item"."commentMsats", "Item"."lastCommentAt", "Item"."weightedVotes",

View File

@ -0,0 +1,2 @@
-- AlterTable
ALTER TABLE "users" ALTER COLUMN "tipDefault" SET DEFAULT 100;

View File

@ -0,0 +1,42 @@
-- AlterTable
ALTER TABLE "Item" ADD COLUMN "upvotes" INTEGER NOT NULL DEFAULT 0;
UPDATE "Item"
SET upvotes = subquery.votes
FROM (SELECT "ItemAct"."itemId", COUNT(DISTINCT "userId") AS votes
FROM "ItemAct"
WHERE "ItemAct".act = 'TIP'
GROUP BY "ItemAct"."itemId") subquery
WHERE "Item".id = subquery."itemId";
CREATE OR REPLACE FUNCTION weighted_votes_after_tip(item_id INTEGER, user_id INTEGER, sats INTEGER) RETURNS INTEGER AS $$
DECLARE
user_trust DOUBLE PRECISION;
sats_past INTEGER;
vote_add INTEGER := 0;
multiplier DOUBLE PRECISION;
BEGIN
-- grab user's trust who is upvoting
SELECT trust INTO user_trust FROM users WHERE id = user_id;
-- in order to add this to weightedVotes, we need to do log((satsN+satsPrior)/satsPrior)
-- so compute sats prior
SELECT SUM(msats) / 1000 INTO sats_past
FROM "ItemAct"
WHERE "userId" = user_id AND "itemId" = item_id AND act IN ('TIP', 'FEE');
IF sats_past IS NULL OR sats_past = 0 THEN
multiplier := LOG(sats);
vote_add := 1;
ELSE
multiplier := LOG((sats+sats_past)/sats_past::FLOAT);
END IF;
-- update item
UPDATE "Item"
SET "weightedVotes" = "weightedVotes" + (user_trust * multiplier), upvotes = upvotes + vote_add
WHERE id = item_id AND "userId" <> user_id;
RETURN 0;
END;
$$ LANGUAGE plpgsql;

View File

@ -252,7 +252,6 @@ model Item {
path Unsupported("LTREE")?
pin Pin? @relation(fields: [pinId], references: [id])
pinId Int?
boost Int @default(0)
uploadId Int?
upload Upload?
paidImgLink Boolean @default(false)
@ -273,6 +272,8 @@ model Item {
weightedVotes Float @default(0)
weightedDownVotes Float @default(0)
msats BigInt @default(0)
boost Int @default(0)
upvotes Int @default(0)
// denormalized comment stats
ncomments Int @default(0)