improved earning: more detail, longer top tail

This commit is contained in:
keyan 2022-09-12 13:55:34 -05:00
parent 1b6a7e7f95
commit 08893d020c
10 changed files with 140 additions and 40 deletions

0
= Normal file
View File

View File

@ -162,18 +162,20 @@ export default {
if (meFull.noteEarning) {
queries.push(
`SELECT id::text, created_at AS "sortTime", FLOOR(msats / 1000) as "earnedSats",
`SELECT min(id)::text, created_at AS "sortTime", FLOOR(sum(msats) / 1000) as "earnedSats",
'Earn' AS type
FROM "Earn"
WHERE "userId" = $1
AND created_at <= $2`
AND created_at <= $2
GROUP BY "userId", created_at`
)
}
}
// we do all this crazy subquery stuff to make 'reward' islands
const notifications = await models.$queryRaw(
`SELECT MAX(id) AS id, MAX("sortTime") AS "sortTime", sum("earnedSats") AS "earnedSats", type
`SELECT MAX(id) AS id, MAX("sortTime") AS "sortTime", sum("earnedSats") AS "earnedSats", type,
MIN("sortTime") AS "minSortTime"
FROM
(SELECT *,
CASE
@ -214,6 +216,26 @@ export default {
JobChanged: {
item: async (n, args, { models }) => getItem(n, { id: n.id }, { models })
},
Earn: {
sources: async (n, args, { me, models }) => {
const [sources] = await models.$queryRaw(`
SELECT
FLOOR(sum(msats) FILTER(WHERE type = 'POST') / 1000) AS posts,
FLOOR(sum(msats) FILTER(WHERE type = 'COMMENT') / 1000) AS comments,
FLOOR(sum(msats) FILTER(WHERE type = 'TIP_POST' OR type = 'TIP_COMMENT') / 1000) AS tips
FROM "Earn"
WHERE "userId" = $1 AND created_at <= $2 AND created_at >= $3
`, Number(me.id), new Date(n.sortTime), new Date(n.minSortTime))
sources.posts ||= 0
sources.comments ||= 0
sources.tips ||= 0
if (sources.posts + sources.comments + sources.tips > 0) {
return sources
}
return null
}
},
Mention: {
mention: async (n, args, { models }) => true,
item: async (n, args, { models }) => getItem(n, { id: n.id }, { models })

View File

@ -103,11 +103,12 @@ export default {
AND "ItemAct".created_at <= $2
GROUP BY "Item".id)`)
queries.push(
`(SELECT ('earn' || "Earn".id) as id, "Earn".id as "factId", NULL as bolt11,
created_at as "createdAt", msats,
`(SELECT ('earn' || min("Earn".id)) as id, min("Earn".id) as "factId", NULL as bolt11,
created_at as "createdAt", sum(msats),
0 as "msatsFee", NULL as status, 'earn' as type
FROM "Earn"
WHERE "Earn"."userId" = $1 AND "Earn".created_at <= $2)`)
WHERE "Earn"."userId" = $1 AND "Earn".created_at <= $2
GROUP BY "userId", created_at)`)
}
if (include.has('spent')) {

View File

@ -32,9 +32,16 @@ export default gql`
sortTime: String!
}
type EarnSources {
posts: Int!
comments: Int!
tips: Int!
}
type Earn {
earnedSats: Int!
sortTime: String!
sources: EarnSources
}
type InvoicePaid {

View File

@ -74,8 +74,14 @@ function Notification ({ n }) {
<HandCoin className='align-self-center fill-boost mx-1' width={24} height={24} style={{ flex: '0 0 24px', transform: 'rotateY(180deg)' }} />
<div className='ml-2'>
<div className='font-weight-bold text-boost'>
you stacked {n.earnedSats} sats <small className='text-muted ml-1'>{timeSince(new Date(n.sortTime))}</small>
you stacked {n.earnedSats} sats in rewards<small className='text-muted ml-1'>{timeSince(new Date(n.sortTime))}</small>
</div>
{n.sources &&
<div style={{ fontSize: '80%', color: 'var(--theme-grey)' }}>
{n.sources.posts > 0 && <span>{n.sources.posts} sats for top posts</span>}
{n.sources.comments > 0 && <span>{n.sources.posts > 0 && ' \\ '}{n.sources.comments} sats for top comments</span>}
{n.sources.tips > 0 && <span>{(n.sources.comments > 0 || n.sources.posts > 0) && ' \\ '}{n.sources.tips} sats for tipping top content early</span>}
</div>}
<div className='pb-1' style={{ lineHeight: '140%' }}>
SN distributes the sats it earns back to its best users daily. These sats come from <Link href='/~jobs' passHref><a>jobs</a></Link>, boost, and posting fees.
</div>

View File

@ -31,6 +31,11 @@ export const NOTIFICATIONS = gql`
... on Earn {
sortTime
earnedSats
sources {
posts
comments
tips
}
}
... on Reply {
sortTime

View File

@ -0,0 +1,10 @@
-- CreateEnum
CREATE TYPE "EarnType" AS ENUM ('POST', 'COMMENT', 'TIP_COMMENT', 'TIP_POST');
-- AlterTable
ALTER TABLE "Earn" ADD COLUMN "rank" INTEGER,
ADD COLUMN "type" "EarnType",
ADD COLUMN "typeId" INTEGER;
-- CreateIndex
CREATE INDEX "Earn.created_at_userId_index" ON "Earn"("created_at", "userId");

View File

@ -0,0 +1,16 @@
CREATE OR REPLACE FUNCTION earn(user_id INTEGER, earn_msats INTEGER, created_at TIMESTAMP(3),
type "EarnType", type_id INTEGER, rank INTEGER)
RETURNS void AS $$
DECLARE
BEGIN
PERFORM ASSERT_SERIALIZED();
-- insert into earn
INSERT INTO "Earn" (msats, "userId", created_at, type, "typeId", rank)
VALUES (earn_msats, user_id, created_at, type, type_id, rank);
-- give the user the sats
UPDATE users
SET msats = msats + earn_msats, "stackedMsats" = "stackedMsats" + earn_msats
WHERE id = user_id;
END;
$$ LANGUAGE plpgsql;

View File

@ -88,6 +88,13 @@ model Upload {
@@index([userId])
}
enum EarnType {
POST
COMMENT
TIP_COMMENT
TIP_POST
}
model Earn {
id Int @id @default(autoincrement())
createdAt DateTime @default(now()) @map(name: "created_at")
@ -97,8 +104,13 @@ model Earn {
user User @relation(fields: [userId], references: [id])
userId Int
type EarnType?
typeId Int?
rank Int?
@@index([createdAt])
@@index([userId])
@@index([createdAt, userId])
}
model LnAuth {

View File

@ -2,8 +2,7 @@ const serialize = require('../api/resolvers/serial')
const ITEM_EACH_REWARD = 3.0
const UPVOTE_EACH_REWARD = 6.0
const TOP_ITEMS = 21
const EARLY_MULTIPLIER_MAX = 100.0
const TOP_PERCENTILE = 21
// TODO: use a weekly trust measure or make trust decay
function earn ({ models }) {
@ -11,7 +10,7 @@ function earn ({ models }) {
console.log('running', name)
// compute how much sn earned today
const [{ sum }] = await models.$queryRaw`
let [{ sum }] = await models.$queryRaw`
SELECT sum("ItemAct".sats)
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
@ -19,10 +18,13 @@ function earn ({ models }) {
OR ("ItemAct".act IN ('VOTE','POLL') AND "Item"."userId" = "ItemAct"."userId"))
AND "ItemAct".created_at > now_utc() - INTERVAL '1 day'`
// convert to msats
sum = sum * 1000
/*
How earnings work:
1/3: top 21 posts over last 36 hours, scored on a relative basis
1/3: top 21 comments over last 36 hours, scored on a relative basis
1/3: top 21% posts over last 36 hours, scored on a relative basis
1/3: top 21% comments over last 36 hours, scored on a relative basis
1/3: top upvoters of top posts/comments, scored on:
- their trust
- how much they tipped
@ -30,20 +32,28 @@ function earn ({ models }) {
- how the post/comment scored
*/
// get earners { id, earnings }
if (sum <= 0) {
console.log('done', name, 'no earning')
return
}
// get earners { userId, id, type, rank, proportion }
const earners = await models.$queryRaw(`
WITH item_ratios AS (
SELECT *,
"weightedVotes"/coalesce(NULLIF(sum("weightedVotes") OVER (PARTITION BY "parentId" IS NULL),0), ${TOP_ITEMS}) AS ratio
FROM (
SELECT *,
ROW_NUMBER() OVER (PARTITION BY "parentId" IS NULL ORDER BY "weightedVotes" desc) AS r
FROM
"Item"
WHERE created_at >= now_utc() - interval '36 hours'
) x
WHERE x.r <= ${TOP_ITEMS}
),
SELECT *,
CASE WHEN "parentId" IS NULL THEN 'POST' ELSE 'COMMENT' END as type,
CASE WHEN "weightedVotes" > 0 THEN "weightedVotes"/(sum("weightedVotes") OVER (PARTITION BY "parentId" IS NULL)) ELSE 0 END AS ratio
FROM (
SELECT *,
NTILE(100) OVER (PARTITION BY "parentId" IS NULL ORDER BY "weightedVotes" desc) AS percentile,
ROW_NUMBER() OVER (PARTITION BY "parentId" IS NULL ORDER BY "weightedVotes" desc) AS rank
FROM
"Item"
WHERE created_at >= now_utc() - interval '36 hours'
AND "weightedVotes" > 0
) x
WHERE x.percentile <= ${TOP_PERCENTILE}
),
upvoters AS (
SELECT "ItemAct"."userId", item_ratios.id, item_ratios.ratio, item_ratios."parentId",
sum("ItemAct".sats) as tipped, min("ItemAct".created_at) as acted_at
@ -54,36 +64,47 @@ function earn ({ models }) {
GROUP BY "ItemAct"."userId", item_ratios.id, item_ratios.ratio, item_ratios."parentId"
),
upvoter_ratios AS (
SELECT "userId", sum(early_multiplier*tipped_ratio*ratio*users.trust) as upvoting_score,
"parentId" IS NULL as "isPost"
SELECT "userId", sum(early_multiplier*tipped_ratio*ratio*users.trust) as upvoter_ratio,
"parentId" IS NULL as "isPost", CASE WHEN "parentId" IS NULL THEN 'TIP_POST' ELSE 'TIP_COMMENT' END as type
FROM (
SELECT *,
${EARLY_MULTIPLIER_MAX}/(ROW_NUMBER() OVER (partition by id order by acted_at asc)) AS early_multiplier,
1/(ROW_NUMBER() OVER (partition by id order by acted_at asc)) AS early_multiplier,
tipped::float/(sum(tipped) OVER (partition by id)) tipped_ratio
FROM upvoters
) u
JOIN users on "userId" = users.id
GROUP BY "userId", "parentId" IS NULL
)
SELECT "userId" as id, FLOOR(sum(proportion)*${sum}*1000) as earnings
FROM (
SELECT "userId",
upvoting_score/(sum(upvoting_score) OVER (PARTITION BY "isPost"))/${UPVOTE_EACH_REWARD} as proportion
FROM upvoter_ratios
UNION ALL
SELECT "userId", ratio/${ITEM_EACH_REWARD} as proportion
FROM item_ratios
) a
GROUP BY "userId"
HAVING FLOOR(sum(proportion)*${sum}) >= 1`)
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"))/${UPVOTE_EACH_REWARD} as proportion
FROM upvoter_ratios
WHERE upvoter_ratio > 0
UNION ALL
SELECT "userId", id, type, rank, ratio/${ITEM_EACH_REWARD} as proportion
FROM item_ratios`)
// in order to group earnings for users we use the same createdAt time for
// all earnings
const now = new Date(new Date().getTime())
// this is just a sanity check because it seems like a good idea
let total = 0
// for each earner, serialize earnings
// we do this for each earner because we don't need to serialize
// all earner updates together
earners.forEach(async earner => {
if (earner.earnings > 0) {
const earnings = Math.floor(earner.proportion * sum)
total += earnings
if (total > sum) {
console.log('total exceeds sum', name)
return
}
if (earnings > 0) {
await serialize(models,
models.$executeRaw`SELECT earn(${earner.id}, ${earner.earnings})`)
models.$executeRaw`SELECT earn(${earner.userId}, ${earnings},
${now}, ${earner.type}, ${earner.id}, ${earner.rank})`)
}
})