From e913ab71ada66dce0129ae9bff3d56598a616a3f Mon Sep 17 00:00:00 2001 From: keyan Date: Wed, 9 Aug 2023 21:27:53 -0500 Subject: [PATCH] more even rewards --- api/resolvers/rewards.js | 17 +--- .../migration.sql | 13 +++ prisma/schema.prisma | 3 + worker/earn.js | 84 +++++++++++-------- 4 files changed, 71 insertions(+), 46 deletions(-) create mode 100644 prisma/migrations/20230809220717_rewards_indices/migration.sql diff --git a/api/resolvers/rewards.js b/api/resolvers/rewards.js index f7e6fdd4..526bf9f3 100644 --- a/api/resolvers/rewards.js +++ b/api/resolvers/rewards.js @@ -5,15 +5,6 @@ import serialize from './serial' export default { Query: { expectedRewards: async (parent, args, { models }) => { - // get the last reward time, then get all contributions to rewards since then - const lastReward = await models.earn.findFirst({ - orderBy: { - createdAt: 'desc' - } - }) - - if (!lastReward) return { total: 0, sources: [] } - const [result] = await models.$queryRaw` SELECT coalesce(FLOOR(sum(sats)), 0) as total, json_build_array( json_build_object('name', 'donations', 'value', coalesce(FLOOR(sum(sats) FILTER(WHERE type = 'DONATION')), 0)), @@ -24,15 +15,15 @@ export default { FROM ( (SELECT ("ItemAct".msats - COALESCE("ReferralAct".msats, 0)) / 1000.0 as sats, act::text as type FROM "ItemAct" - LEFT JOIN "ReferralAct" ON "ItemAct".id = "ReferralAct"."itemActId" - WHERE "ItemAct".created_at > ${lastReward.createdAt} AND "ItemAct".act <> 'TIP') + LEFT JOIN "ReferralAct" ON "ReferralAct"."itemActId" = "ItemAct".id + WHERE date_trunc('day', "ItemAct".created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = date_trunc('day', now() AT TIME ZONE 'America/Chicago') AND "ItemAct".act <> 'TIP') UNION ALL (SELECT sats::FLOAT, 'DONATION' as type FROM "Donation" - WHERE created_at > ${lastReward.createdAt}) + WHERE date_trunc('day', created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = date_trunc('day', now() AT TIME ZONE 'America/Chicago')) ) subquery` - return result + return result || { total: 0, sources: [] } } }, Mutation: { diff --git a/prisma/migrations/20230809220717_rewards_indices/migration.sql b/prisma/migrations/20230809220717_rewards_indices/migration.sql new file mode 100644 index 00000000..d24f27e6 --- /dev/null +++ b/prisma/migrations/20230809220717_rewards_indices/migration.sql @@ -0,0 +1,13 @@ +-- CreateIndex +CREATE INDEX "ReferralAct_referrerId_idx" ON "ReferralAct"("referrerId"); + +-- CreateIndex +CREATE INDEX "ReferralAct_itemActId_idx" ON "ReferralAct"("itemActId"); + +-- This is an empty migration. + +CREATE INDEX IF NOT EXISTS "ItemAct.created_at_day_index" + ON "ItemAct"(date_trunc('day', created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')); + +CREATE INDEX IF NOT EXISTS "Donation.created_at_day_index" + ON "Donation"(date_trunc('day', created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')); \ No newline at end of file diff --git a/prisma/schema.prisma b/prisma/schema.prisma index bb517f5a..c02198cf 100644 --- a/prisma/schema.prisma +++ b/prisma/schema.prisma @@ -350,6 +350,9 @@ model ReferralAct { msats BigInt itemAct ItemAct @relation(fields: [itemActId], references: [id], onDelete: Cascade) referrer User @relation(fields: [referrerId], references: [id], onDelete: Cascade) + + @@index([referrerId]) + @@index([itemActId]) } model ItemAct { diff --git a/worker/earn.js b/worker/earn.js index de2f51dc..9d4e492e 100644 --- a/worker/earn.js +++ b/worker/earn.js @@ -3,41 +3,45 @@ const serialize = require('../api/resolvers/serial') // const ITEM_EACH_REWARD = 3.0 // const UPVOTE_EACH_REWARD = 6.0 const TOP_PERCENTILE = 21 +const TOTAL_UPPER_BOUND_MSATS = 1000000000 +const REDUCE_REWARDS = [616, 6030, 946, 4502] function earn ({ models }) { return async function ({ name }) { console.log('running', name) // compute how much sn earned today - const [{ sum: actSum }] = await models.$queryRaw` - SELECT coalesce(sum("ItemAct".msats - coalesce("ReferralAct".msats, 0)), 0) as sum - FROM "ItemAct" - JOIN "Item" ON "ItemAct"."itemId" = "Item".id - LEFT JOIN "ReferralAct" ON "ItemAct".id = "ReferralAct"."itemActId" - WHERE "ItemAct".act <> 'TIP' - AND "ItemAct".created_at > now_utc() - INTERVAL '1 day'` + const [{ sum: sumDecimal }] = await models.$queryRaw` + SELECT coalesce(sum(msats), 0) as sum + FROM ( + (SELECT ("ItemAct".msats - COALESCE("ReferralAct".msats, 0)) as msats + FROM "ItemAct" + LEFT JOIN "ReferralAct" ON "ReferralAct"."itemActId" = "ItemAct".id + WHERE date_trunc('day', "ItemAct".created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = date_trunc('day', (now() - interval '1 day') AT TIME ZONE 'America/Chicago') AND "ItemAct".act <> 'TIP') + UNION ALL + (SELECT sats * 1000 as msats + FROM "Donation" + WHERE date_trunc('day', created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = date_trunc('day', (now() - interval '1 day') AT TIME ZONE 'America/Chicago')) + ) subquery` - const [{ sum: donatedSum }] = await models.$queryRaw` - SELECT coalesce(sum(sats), 0) as sum - FROM "Donation" - WHERE created_at > now_utc() - INTERVAL '1 day'` - - // XXX prisma returns wonky types from raw queries ... so be extra - // careful with them - const sum = Number(actSum) + (Number(donatedSum) * 1000) - - if (sum <= 0) { + // XXX primsa will return a Decimal (https://mikemcl.github.io/decimal.js) + // because sum of a BIGINT returns a NUMERIC type (https://www.postgresql.org/docs/13/functions-aggregate.html) + // and Decimal is what prisma maps it to https://www.prisma.io/docs/concepts/components/prisma-client/raw-database-access#raw-query-type-mapping + // so check it before coercing to Number + if (!sumDecimal || sumDecimal.lessThanOrEqualTo(0)) { console.log('done', name, 'no sats to award today') return } - // extra sanity check on rewards ... if it more than 1m sats, we - // probably have a bug somewhere - if (sum > 1000000000) { - console.log('done', name, 'error: too many sats to award today') + // extra sanity check on rewards ... if it's more than upper bound, we + // probably have a bug somewhere or we've grown A LOT + if (sumDecimal.greaterThan(TOTAL_UPPER_BOUND_MSATS)) { + console.log('done', name, 'error: too many sats to award today', sumDecimal) return } + const sum = Number(sumDecimal) + console.log(name, 'giving away', sum, 'msats') /* @@ -54,7 +58,8 @@ function earn ({ models }) { */ // get earners { userId, id, type, rank, proportion } - const earners = await models.$queryRawUnsafe(` + const earners = await models.$queryRaw` + -- get top 21% of posts and comments WITH item_ratios AS ( SELECT *, CASE WHEN "parentId" IS NULL THEN 'POST' ELSE 'COMMENT' END as type, @@ -70,20 +75,32 @@ function earn ({ models }) { ) x WHERE x.percentile <= ${TOP_PERCENTILE} ), - upvoters AS ( - SELECT "ItemAct"."userId", item_ratios.id, item_ratios.ratio, item_ratios."parentId", - sum("ItemAct".msats) as tipped, min("ItemAct".created_at) as acted_at - FROM item_ratios - JOIN "ItemAct" on "ItemAct"."itemId" = item_ratios.id - WHERE act = 'TIP' - GROUP BY "ItemAct"."userId", item_ratios.id, item_ratios.ratio, item_ratios."parentId" + -- get top upvoters of top posts and comments + upvoter_islands AS ( + SELECT "ItemAct"."userId", item_ratios.id, item_ratios.ratio, item_ratios."parentId", + "ItemAct".msats as tipped, "ItemAct".created_at as acted_at, + ROW_NUMBER() OVER (partition by item_ratios.id order by "ItemAct".created_at asc) + - ROW_NUMBER() OVER (partition by item_ratios.id, "ItemAct"."userId" order by "ItemAct".created_at asc) AS island + FROM item_ratios + JOIN "ItemAct" on "ItemAct"."itemId" = item_ratios.id + WHERE act = 'TIP' ), + -- isolate contiguous upzaps from the same user on the same item so that when we take the log + -- of the upzaps it accounts for successive zaps and does disproporionately reward them + upvoters AS ( + SELECT "userId", id, ratio, "parentId", log(sum(tipped) / 1000) as tipped, min(acted_at) as acted_at + FROM upvoter_islands + GROUP BY "userId", id, ratio, "parentId", island + ), + -- the relative contribution of each upvoter to the post/comment + -- early multiplier: 10/ln(early_rank + e) + -- we also weight by trust in a step wise fashion upvoter_ratios AS ( - SELECT "userId", sum(early_multiplier*tipped_ratio*ratio*users.trust) as upvoter_ratio, + SELECT "userId", sum(early_multiplier*tipped_ratio*ratio*CASE WHEN users.id = ANY (${REDUCE_REWARDS}) THEN 0.2 ELSE CEIL(users.trust*2) END) as upvoter_ratio, "parentId" IS NULL as "isPost", CASE WHEN "parentId" IS NULL THEN 'TIP_POST' ELSE 'TIP_COMMENT' END as type FROM ( SELECT *, - 1/(ROW_NUMBER() OVER (partition by id order by acted_at asc)) AS early_multiplier, + 10.0/LN(ROW_NUMBER() OVER (partition by id order by acted_at asc) + EXP(1.0)) AS early_multiplier, tipped::float/(sum(tipped) OVER (partition by id)) tipped_ratio FROM upvoters ) u @@ -93,7 +110,8 @@ function earn ({ models }) { SELECT "userId", NULL as id, type, ROW_NUMBER() OVER (PARTITION BY "isPost" ORDER BY upvoter_ratio DESC) as rank, upvoter_ratio/(sum(upvoter_ratio) OVER (PARTITION BY "isPost"))/2 as proportion FROM upvoter_ratios - WHERE upvoter_ratio > 0`) + WHERE upvoter_ratio > 0 + ORDER BY "isPost", rank ASC` // in order to group earnings for users we use the same createdAt time for // all earnings @@ -113,7 +131,7 @@ function earn ({ models }) { return } - console.log('stacker', earner.userId, 'earned', earnings) + console.log('stacker', earner.userId, 'earned', earnings, 'proportion', earner.proportion, 'rank', earner.rank, 'type', earner.type) if (earnings > 0) { await serialize(models,