Referral Rewards (#1262)

* referral rewards

* make referral notifications consistent

* remove plpgsql from earn job

* remove dead code

* remove debug logging
This commit is contained in:
Keyan 2024-07-10 19:23:05 -05:00 committed by GitHub
parent 6cf16d3da7
commit c6554d3ca7
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
19 changed files with 501 additions and 133 deletions

View File

@ -1,26 +1,5 @@
import { timeUnitForRange, whenRange } from '@/lib/time'
export function withClause (range) {
const unit = timeUnitForRange(range)
return `
WITH range_values AS (
SELECT date_trunc('${unit}', $1) as minval,
date_trunc('${unit}', $2) as maxval
),
times AS (
SELECT generate_series(minval, maxval, interval '1 ${unit}') as time
FROM range_values
)
`
}
export function intervalClause (range, table) {
const unit = timeUnitForRange(range)
return `date_trunc('${unit}', "${table}".created_at) >= date_trunc('${unit}', $1) AND date_trunc('${unit}', "${table}".created_at) <= date_trunc('${unit}', $2) `
}
export function viewIntervalClause (range, view) {
const unit = timeUnitForRange(range)
return `"${view}".t >= date_trunc('${unit}', timezone('America/Chicago', $1)) AND date_trunc('${unit}', "${view}".t) <= date_trunc('${unit}', timezone('America/Chicago', $2)) `
@ -42,8 +21,8 @@ export function viewGroup (range, view) {
${view}(
date_trunc('hour', timezone('America/Chicago', now())),
date_trunc('hour', timezone('America/Chicago', now())), '1 hour'::INTERVAL, 'hour')
WHERE "${view}".t >= date_trunc('${unit}', timezone('America/Chicago', $1))
AND "${view}".t <= date_trunc('${unit}', timezone('America/Chicago', $2)))
WHERE "${view}".t >= date_trunc('hour', timezone('America/Chicago', $1))
AND "${view}".t <= date_trunc('hour', timezone('America/Chicago', $2)))
) u`
}

View File

@ -284,6 +284,7 @@ export default {
FROM "Earn"
WHERE "userId" = $1
AND created_at < $2
AND (type IS NULL OR type NOT IN ('FOREVER_REFERRAL', 'ONE_DAY_REFERRAL'))
GROUP BY "userId", created_at
ORDER BY "sortTime" DESC
LIMIT ${LIMIT})`
@ -299,6 +300,17 @@ export default {
ORDER BY "sortTime" DESC
LIMIT ${LIMIT})`
)
queries.push(
`(SELECT min(id)::text, created_at AS "sortTime", FLOOR(sum(msats) / 1000) as "earnedSats",
'ReferralReward' AS type
FROM "Earn"
WHERE "userId" = $1
AND created_at < $2
AND type IN ('FOREVER_REFERRAL', 'ONE_DAY_REFERRAL')
GROUP BY "userId", created_at
ORDER BY "sortTime" DESC
LIMIT ${LIMIT})`
)
}
if (meFull.noteCowboyHat) {
@ -487,6 +499,22 @@ export default {
return null
}
},
ReferralReward: {
sources: async (n, args, { me, models }) => {
const [sources] = await models.$queryRawUnsafe(`
SELECT
COALESCE(FLOOR(sum(msats) FILTER(WHERE type = 'FOREVER_REFERRAL') / 1000), 0) AS forever,
COALESCE(FLOOR(sum(msats) FILTER(WHERE type = 'ONE_DAY_REFERRAL') / 1000), 0) AS "oneDay"
FROM "Earn"
WHERE "userId" = $1 AND created_at = $2
`, Number(me.id), new Date(n.sortTime))
if (sources.forever + sources.oneDay > 0) {
return sources
}
return null
}
},
Mention: {
mention: async (n, args, { models }) => true,
item: async (n, args, { models, me }) => getItem(n, { id: n.id }, { models, me })

View File

@ -1,6 +1,6 @@
import { GraphQLError } from 'graphql'
import { withClause, intervalClause } from './growth'
import { timeUnitForRange, whenRange } from '@/lib/time'
import { viewGroup } from './growth'
export default {
Query: {
@ -11,46 +11,18 @@ export default {
const range = whenRange(when, from, to)
const [{ totalSats }] = await models.$queryRawUnsafe(`
SELECT COALESCE(FLOOR(sum(msats) / 1000), 0) as "totalSats"
FROM "ReferralAct"
WHERE ${intervalClause(range, 'ReferralAct')}
AND "ReferralAct"."referrerId" = $3
`, ...range, Number(me.id))
const [{ totalReferrals }] = await models.$queryRawUnsafe(`
SELECT count(*)::INTEGER as "totalReferrals"
FROM users
WHERE ${intervalClause(range, 'users')}
AND "referrerId" = $3
`, ...range, Number(me.id))
const stats = await models.$queryRawUnsafe(
`${withClause(range)}
SELECT time, json_build_array(
json_build_object('name', 'referrals', 'value', count(*) FILTER (WHERE act = 'REFERREE')),
json_build_object('name', 'sats', 'value', FLOOR(COALESCE(sum(msats) FILTER (WHERE act IN ('BOOST', 'STREAM', 'FEE')), 0)))
return await models.$queryRawUnsafe(`
SELECT date_trunc('${timeUnitForRange(range)}', t) at time zone 'America/Chicago' as time,
json_build_array(
json_build_object('name', 'referrals', 'value', COALESCE(SUM(referrals), 0)),
json_build_object('name', 'one day referrals', 'value', COALESCE(SUM(one_day_referrals), 0)),
json_build_object('name', 'referral sats', 'value', FLOOR(COALESCE(SUM(msats_referrals), 0) / 1000.0)),
json_build_object('name', 'one day referral sats', 'value', FLOOR(COALESCE(SUM(msats_one_day_referrals), 0) / 1000.0))
) AS data
FROM times
LEFT JOIN
((SELECT "ReferralAct".created_at, "ReferralAct".msats / 1000.0 as msats, "ItemAct".act::text as act
FROM "ReferralAct"
JOIN "ItemAct" ON "ItemAct".id = "ReferralAct"."itemActId"
WHERE ${intervalClause(range, 'ReferralAct')}
AND "ReferralAct"."referrerId" = $3)
UNION ALL
(SELECT created_at, 0.0 as sats, 'REFERREE' as act
FROM users
WHERE ${intervalClause(range, 'users')}
AND "referrerId" = $3)) u ON time = date_trunc('${timeUnitForRange(range)}', u.created_at)
GROUP BY time
ORDER BY time ASC`, ...range, Number(me.id))
return {
totalSats,
totalReferrals,
stats
}
FROM ${viewGroup(range, 'user_stats')}
WHERE id = ${me.id}
GROUP BY time
ORDER BY time ASC`, ...range)
}
}
}

View File

@ -579,7 +579,8 @@ export default {
json_build_object('name', 'comments', 'value', COALESCE(SUM(comments), 0)),
json_build_object('name', 'posts', 'value', COALESCE(SUM(posts), 0)),
json_build_object('name', 'territories', 'value', COALESCE(SUM(territories), 0)),
json_build_object('name', 'referrals', 'value', COALESCE(SUM(referrals), 0))
json_build_object('name', 'referrals', 'value', COALESCE(SUM(referrals), 0)),
json_build_object('name', 'one day referrals', 'value', COALESCE(SUM(one_day_referrals), 0))
) AS data
FROM ${viewGroup(range, 'user_stats')}
WHERE id = ${me.id}
@ -594,6 +595,7 @@ export default {
json_build_object('name', 'zaps', 'value', ROUND(COALESCE(SUM(msats_tipped), 0) / 1000)),
json_build_object('name', 'rewards', 'value', ROUND(COALESCE(SUM(msats_rewards), 0) / 1000)),
json_build_object('name', 'referrals', 'value', ROUND( COALESCE(SUM(msats_referrals), 0) / 1000)),
json_build_object('name', 'one day referrals', 'value', ROUND( COALESCE(SUM(msats_one_day_referrals), 0) / 1000)),
json_build_object('name', 'territories', 'value', ROUND(COALESCE(SUM(msats_revenue), 0) / 1000))
) AS data
FROM ${viewGroup(range, 'user_stats')}
@ -607,6 +609,7 @@ export default {
SELECT date_trunc('${timeUnitForRange(range)}', t) at time zone 'America/Chicago' as time,
json_build_array(
json_build_object('name', 'fees', 'value', FLOOR(COALESCE(SUM(msats_fees), 0) / 1000)),
json_build_object('name', 'zapping', 'value', FLOOR(COALESCE(SUM(msats_zaps), 0) / 1000)),
json_build_object('name', 'donations', 'value', FLOOR(COALESCE(SUM(msats_donated), 0) / 1000)),
json_build_object('name', 'territories', 'value', FLOOR(COALESCE(SUM(msats_billing), 0) / 1000))
) AS data

View File

@ -72,7 +72,16 @@ function oneDayReferral (request, { me }) {
typeId: String(item.id)
})
} else if (referrer.startsWith('profile-')) {
prismaPromise = models.user.findUnique({ where: { name: referrer.slice(8) } })
const name = referrer.slice(8)
// exclude all pages that are not user profiles
if (['api', 'auth', 'day', 'invites', 'invoices', 'referrals', 'rewards',
'satistics', 'settings', 'stackers', 'wallet', 'withdrawals', '404', '500',
'email', 'live', 'login', 'notifications', 'offline', 'search', 'share',
'signup', 'territory', 'recent', 'top', 'edit', 'post', 'rss', 'saloon',
'faq', 'story', 'privacy', 'copyright', 'tos', 'changes', 'guide', 'daily',
'anon', 'ad'].includes(name)) continue
prismaPromise = models.user.findUnique({ where: { name } })
getData = user => ({
referrerId: user.id,
refereeId: parseInt(me.id),

View File

@ -89,6 +89,19 @@ export default gql`
sources: EarnSources
}
type ReferralSources {
id: ID!
forever: Int!
oneDay: Int!
}
type ReferralReward {
id: ID!
earnedSats: Int!
sortTime: Date!
sources: ReferralSources
}
type Revenue {
id: ID!
earnedSats: Int!
@ -143,6 +156,7 @@ export default gql`
| Invitification | Earn | JobChanged | InvoicePaid | WithdrawlPaid | Referral
| Streak | FollowActivity | ForwardedVotification | Revenue | SubStatus
| TerritoryPost | TerritoryTransfer | Reminder | ItemMention | Invoicification
| ReferralReward
type Notifications {
lastChecked: Date

View File

@ -2,12 +2,6 @@ import { gql } from 'graphql-tag'
export default gql`
extend type Query {
referrals(when: String, from: String, to: String): Referrals!
}
type Referrals {
totalSats: Int!
totalReferrals: Int!
stats: [TimeData!]!
referrals(when: String, from: String, to: String): [TimeData!]!
}
`

View File

@ -156,7 +156,7 @@ export function WhenComposedChart ({
data,
lineNames = [], lineAxis = 'left',
areaNames = [], areaAxis = 'left',
barNames = [], barAxis = 'left'
barNames = [], barAxis = 'left', barStackId
}) {
const router = useRouter()
if (!data || data.length === 0) {
@ -189,7 +189,7 @@ export function WhenComposedChart ({
<Tooltip labelFormatter={labelFormatter(when, from, to)} contentStyle={{ color: 'var(--bs-body-color)', backgroundColor: 'var(--bs-body-bg)' }} />
<Legend />
{barNames?.map((v, i) =>
<Bar yAxisId={barAxis} key={v} type='monotone' dataKey={v} name={v} stroke={getColor(i)} fill={getColor(i)} />)}
<Bar yAxisId={barAxis} key={v} stackId={barStackId} type='monotone' dataKey={v} name={v} stroke={getColor(i)} fill={getColor(i)} />)}
{areaNames?.map((v, i) =>
<Area yAxisId={areaAxis} key={v} type='monotone' dataKey={v} name={v} stackId='1' stroke={getColor(barNames.length + i)} fill={getColor(barNames.length + i)} />)}
{lineNames?.map((v, i) =>

View File

@ -10,6 +10,7 @@ import { dayMonthYear, timeSince } from '@/lib/time'
import Link from 'next/link'
import Check from '@/svgs/check-double-line.svg'
import HandCoin from '@/svgs/hand-coin-fill.svg'
import UserAdd from '@/svgs/user-add-fill.svg'
import { LOST_BLURBS, FOUND_BLURBS, UNKNOWN_LINK_REL } from '@/lib/constants'
import CowboyHatIcon from '@/svgs/cowboy.svg'
import BaldIcon from '@/svgs/bald.svg'
@ -62,7 +63,8 @@ function Notification ({ n, fresh }) {
(type === 'TerritoryPost' && <TerritoryPost n={n} />) ||
(type === 'TerritoryTransfer' && <TerritoryTransfer n={n} />) ||
(type === 'Reminder' && <Reminder n={n} />) ||
(type === 'Invoicification' && <Invoicification n={n} />)
(type === 'Invoicification' && <Invoicification n={n} />) ||
(type === 'ReferralReward' && <ReferralReward n={n} />)
}
</NotificationLayout>
)
@ -132,6 +134,7 @@ const defaultOnClick = n => {
if (type === 'Invoicification') return itemLink(n.invoice.item)
if (type === 'WithdrawlPaid') return { href: `/withdrawals/${n.id}` }
if (type === 'Referral') return { href: '/referrals/month' }
if (type === 'ReferralReward') return { href: '/referrals/month' }
if (type === 'Streak') return {}
if (type === 'TerritoryTransfer') return { href: `/~${n.sub.name}` }
@ -172,7 +175,7 @@ function EarnNotification ({ n }) {
return (
<div className='d-flex ms-2 py-1'>
<HandCoin className='align-self-center fill-boost mx-1' width={24} height={24} style={{ flex: '0 0 24px', transform: 'rotateY(180deg)' }} />
<div className='ms-2'>
<div className='mx-2'>
<div className='fw-bold text-boost'>
you stacked {numWithUnits(n.earnedSats, { abbreviate: false })} in rewards<small className='text-muted ms-1 fw-normal' suppressHydrationWarning>{time}</small>
</div>
@ -184,7 +187,29 @@ function EarnNotification ({ n }) {
{n.sources.tipComments > 0 && <span>{(n.sources.comments > 0 || n.sources.posts > 0 || n.sources.tipPosts > 0) && ' \\ '}{numWithUnits(n.sources.tipComments, { abbreviate: false })} for zapping top comments early</span>}
</div>}
<div style={{ lineHeight: '140%' }}>
SN distributes the sats it earns back to its best stackers. These sats come from <Link href='/~jobs'>jobs</Link>, boosts, posting fees, and donations. You can see the rewards pool and make a donation <Link href='/rewards'>here</Link>.
SN distributes the sats it earns to top stackers like you daily. The top stackers make the top posts and comments or zap the top posts and comments early and generously. View the rewards pool and make a donation <Link href='/rewards'>here</Link>.
</div>
<small className='text-muted ms-1 pb-1 fw-normal'>click for details</small>
</div>
</div>
)
}
function ReferralReward ({ n }) {
return (
<div className='d-flex ms-2 py-1'>
<UserAdd className='align-self-center fill-success mx-1' width={24} height={24} style={{ flex: '0 0 24px', transform: 'rotateY(180deg)' }} />
<div className='mx-2'>
<div className='fw-bold text-success'>
you stacked {numWithUnits(n.earnedSats, { abbreviate: false })} in referral rewards<small className='text-muted ms-1 fw-normal' suppressHydrationWarning>{dayMonthYear(new Date(n.sortTime))}</small>
</div>
{n.sources &&
<div style={{ fontSize: '80%', color: 'var(--theme-grey)' }}>
{n.sources.forever > 0 && <span>{numWithUnits(n.sources.forever, { abbreviate: false })} for stackers joining because of you</span>}
{n.sources.oneDay > 0 && <span>{n.sources.oneDay > 0 && ' \\ '}{numWithUnits(n.sources.oneDay, { abbreviate: false })} for stackers referred to content by you today</span>}
</div>}
<div style={{ lineHeight: '140%' }}>
SN gives referral rewards to stackers like you for referring the top stackers daily. You refer stackers when they visit your posts, comments, profile, territory, or if they visit SN through your referral links.
</div>
<small className='text-muted ms-1 pb-1 fw-normal'>click for details</small>
</div>
@ -433,8 +458,8 @@ function WithdrawlPaid ({ n }) {
function Referral ({ n }) {
return (
<small className='fw-bold text-secondary ms-2'>
someone joined via one of your referral links
<small className='fw-bold text-success ms-2'>
<UserAdd className='fill-success me-2' height={21} width={21} style={{ transform: 'rotateY(180deg)' }} />someone joined SN because of you
<small className='text-muted ms-1 fw-normal' suppressHydrationWarning>{timeSince(new Date(n.sortTime))}</small>
</small>
)

View File

@ -99,6 +99,15 @@ export const NOTIFICATIONS = gql`
tipComments
}
}
... on ReferralReward {
id
sortTime
earnedSats
sources {
forever
oneDay
}
}
... on Referral {
id
sortTime

View File

@ -21,14 +21,10 @@ const REFERRALS = gql`
query Referrals($when: String!, $from: String, $to: String)
{
referrals(when: $when, from: $from, to: $to) {
totalSats
totalReferrals
stats {
time
data {
name
value
}
time
data {
name
value
}
}
}`
@ -54,7 +50,12 @@ export default function Referrals ({ ssrData }) {
const { data } = useQuery(REFERRALS, { variables: { when: router.query.when, from: router.query.from, to: router.query.to } })
if (!data && !ssrData) return <PageLoading />
const { referrals: { totalSats, totalReferrals, stats } } = data || ssrData
const { referrals } = data || ssrData
const totalSats = referrals.reduce(
(total, a) => total + a.data?.filter(d => d.name.endsWith('sats')).reduce(
(acc, d) => acc + d.value,
0),
0)
const when = router.query.when
@ -62,7 +63,7 @@ export default function Referrals ({ ssrData }) {
<CenterLayout footerLinks>
<div className='fw-bold text-muted text-center pt-5 pb-3 d-flex align-items-center justify-content-center flex-wrap'>
<h4 className='fw-bold text-muted text-center d-flex align-items-center justify-content-center'>
{numWithUnits(totalReferrals, { unitPlural: 'referrals', unitSingular: 'referral' })} & {numWithUnits(totalSats, { abbreviate: false })} in the last
{numWithUnits(totalSats, { abbreviate: false })} in the last
<Select
groupClassName='mb-0 mx-2'
className='w-auto'
@ -91,7 +92,13 @@ export default function Referrals ({ ssrData }) {
when={router.query.when}
/>}
</div>
<WhenComposedChart data={stats} lineNames={['sats']} barNames={['referrals']} barAxis='right' />
<WhenComposedChart
data={referrals}
areaNames={['referral sats', 'one day referral sats']}
barNames={['referrals', 'one day referrals']}
barAxis='right'
barStackId={1}
/>
<div
className='text-small pt-5 px-3 d-flex w-100 align-items-center'
@ -106,13 +113,16 @@ export default function Referrals ({ ssrData }) {
/>
</div>
<ul className='py-3 text-muted'>
<li>{`appending /r/${me.name} to any SN link makes it a ref link`}
<li>earn 10% of a stacker's <Link href='/rewards'>rewards</Link> in perpetuity if they sign up from your referral links</li>
<li>in addition, earn 10% of a stacker's <Link href='/rewards'>rewards</Link> for the day if they follow your refrral links the most that day</li>
<li>nearly all sn links are referral links:
<ul>
<li>e.g. https://stacker.news/items/1/r/{me.name}</li>
<li>your profile link is an implicit referral link</li>
<li>all links to post and comments are implicit referral links attributed to the OP</li>
<li>links to territories are implicit referral links attributed to the territory founder</li>
</ul>
</li>
<li>earn 21% of boost and job fees spent by referred stackers</li>
<li>earn 2.1% of all zaps received by referred stackers</li>
<li>appending /r/{me.name} to any SN link makes it a ref link to {me.name}</li>
<li><Link href='/invites'>invite links</Link> are also implicitly referral links</li>
</ul>
</CenterLayout>

View File

@ -110,10 +110,13 @@ export default function Rewards ({ ssrData }) {
if (!dat) return <PageLoading />
function EstimatedReward ({ rank }) {
const referrerReward = Math.floor(total * proportions[rank - 1] * 0.2)
const reward = Math.floor(total * proportions[rank - 1]) - referrerReward
return (
<div className='text-muted fst-italic'>
<small>
<span>estimated reward: {numWithUnits(Math.floor(total * proportions[rank - 1]))}</span>
<span>estimated reward: {numWithUnits(reward)} <small className='fw-light'>(+ {numWithUnits(referrerReward)} to referrers)</small></span>
</small>
</div>
)

View File

@ -48,7 +48,6 @@ export default function Satistics ({ ssrData }) {
const totalStacked = userStatsIncomingSats.reduce((total, a) => total + a.data?.reduce((acc, d) => acc + d.value, 0), 0)
const totalSpent = userStatsOutgoingSats.reduce((total, a) => total + a.data?.reduce((acc, d) => acc + d.value, 0), 0)
const totalEngagement = userStatsActions.reduce((total, a) => total + a.data?.reduce((acc, d) => acc + d.value, 0), 0)
return (
<Layout>
@ -59,8 +58,8 @@ export default function Satistics ({ ssrData }) {
<UsageHeader pathname='satistics/graphs' />
<div className='mt-3'>
<div className='d-flex row justify-content-between'>
<div className='col-md-4 mb-2'>
<h4>stacked</h4>
<div className='col-md-6 mb-2'>
<h4 className='w-100 text-center'>stacked</h4>
<div className='card'>
<div className='card-body'>
<SatisticsTooltip overlayText={numWithUnits(totalStacked, { abbreviate: false, format: true })}>
@ -71,8 +70,8 @@ export default function Satistics ({ ssrData }) {
</div>
</div>
</div>
<div className='col-md-4 mb-2'>
<h4>spent</h4>
<div className='col-md-6 mb-2'>
<h4 className='w-100 text-center'>spent</h4>
<div className='card'>
<div className='card-body'>
<SatisticsTooltip overlayText={numWithUnits(totalSpent, { abbreviate: false, format: true })}>
@ -83,16 +82,6 @@ export default function Satistics ({ ssrData }) {
</div>
</div>
</div>
<div className='col-md-4'>
<h4>actions</h4>
<div className='card'>
<div className='card-body'>
<h2 className='text-center mb-0 text-muted'>
{new Intl.NumberFormat().format(totalEngagement)}
</h2>
</div>
</div>
</div>
</div>
<div className='row mt-5'>
{userStatsIncomingSats.length > 0 &&
@ -110,7 +99,7 @@ export default function Satistics ({ ssrData }) {
{userStatsActions.length > 0 &&
<div className='col-md-12'>
<div className='text-center text-muted fw-bold'>items</div>
<WhenComposedChart data={userStatsActions} areaNames={['posts', 'comments']} areaAxis='left' lineNames={['territories', 'referrals']} lineAxis='right' />
<WhenComposedChart data={userStatsActions} areaNames={['posts', 'comments']} areaAxis='left' lineNames={['territories', 'referrals', 'one day referrals']} lineAxis='right' />
</div>}
</div>
</div>

View File

@ -0,0 +1,32 @@
ALTER TYPE "EarnType" ADD VALUE 'FOREVER_REFERRAL';
ALTER TYPE "EarnType" ADD VALUE 'ONE_DAY_REFERRAL';
-- delete attributing one day referrals to pages
DELETE FROM "OneDayReferral"
WHERE "typeId" IN (
SELECT id::text
FROM users
WHERE name IN (
'api', 'auth', 'day', 'invites', 'invoices', 'referrals', 'rewards',
'satistics', 'settings', 'stackers', 'wallet', 'withdrawals', '404', '500',
'email', 'live', 'login', 'notifications', 'offline', 'search', 'share',
'signup', 'territory', 'recent', 'top', 'edit', 'post', 'rss', 'saloon',
'faq', 'story', 'privacy', 'copyright', 'tos', 'changes', 'guide', 'daily',
'anon', 'ad'
)
);
-- delete attributing forever referrals to pages
UPDATE users SET "referrerId" = NULL
WHERE "referrerId" IN (
SELECT id
FROM users
WHERE name IN (
'api', 'auth', 'day', 'invites', 'invoices', 'referrals', 'rewards',
'satistics', 'settings', 'stackers', 'wallet', 'withdrawals', '404', '500',
'email', 'live', 'login', 'notifications', 'offline', 'search', 'share',
'signup', 'territory', 'recent', 'top', 'edit', 'post', 'rss', 'saloon',
'faq', 'story', 'privacy', 'copyright', 'tos', 'changes', 'guide', 'daily',
'anon', 'ad'
)
);

View File

@ -0,0 +1,223 @@
-- add referrals to user stats and more fields while we're at it
DROP FUNCTION IF EXISTS user_stats(timestamp without time zone,timestamp without time zone,interval,text) CASCADE;
CREATE OR REPLACE FUNCTION user_stats(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (
t TIMESTAMP(3), id INTEGER, comments BIGINT, posts BIGINT, territories BIGINT,
referrals BIGINT, one_day_referrals BIGINT, msats_tipped BIGINT, msats_rewards BIGINT,
msats_referrals BIGINT, msats_one_day_referrals BIGINT,
msats_revenue BIGINT, msats_stacked BIGINT, msats_fees BIGINT, msats_donated BIGINT,
msats_billing BIGINT, msats_zaps BIGINT, msats_spent BIGINT)
LANGUAGE plpgsql
AS $$
DECLARE
min_utc TIMESTAMP(3) := timezone('utc', min AT TIME ZONE 'America/Chicago');
BEGIN
RETURN QUERY
SELECT period.t,
"userId" as id,
-- counts
(sum(quantity) FILTER (WHERE type = 'COMMENT'))::BIGINT as comments,
(sum(quantity) FILTER (WHERE type = 'POST'))::BIGINT as posts,
(sum(quantity) FILTER (WHERE type = 'TERRITORY'))::BIGINT as territories,
(sum(quantity) FILTER (WHERE type = 'REFERRAL'))::BIGINT as referrals,
(sum(quantity) FILTER (WHERE type = 'ONE_DAY_REFERRAL_COUNT'))::BIGINT as one_day_referrals,
-- stacking
(sum(quantity) FILTER (WHERE type = 'TIPPEE'))::BIGINT as msats_tipped,
(sum(quantity) FILTER (WHERE type = 'EARN'))::BIGINT as msats_rewards,
(sum(quantity) FILTER (WHERE type = 'REFERRAL_ACT' OR type = 'FOREVER_REFERRAL'))::BIGINT as msats_referrals,
(sum(quantity) FILTER (WHERE type = 'ONE_DAY_REFERRAL'))::BIGINT as msats_one_day_referrals,
(sum(quantity) FILTER (WHERE type = 'REVENUE'))::BIGINT as msats_revenue,
(sum(quantity) FILTER (WHERE type IN ('TIPPEE', 'EARN', 'REFERRAL_ACT', 'REVENUE', 'ONE_DAY_REFERRAL', 'FOREVER_REFERRAL')))::BIGINT as msats_stacked,
-- spending
(sum(quantity) FILTER (WHERE type IN ('BOOST', 'FEE', 'STREAM', 'POLL', 'DONT_LIKE_THIS')))::BIGINT as msats_fees,
(sum(quantity) FILTER (WHERE type = 'DONATION'))::BIGINT as msats_donated,
(sum(quantity) FILTER (WHERE type = 'BILLING'))::BIGINT as msats_billing,
(sum(quantity) FILTER (WHERE type = 'TIP'))::BIGINT as msats_zaps,
(sum(quantity) FILTER (WHERE type IN ('BOOST', 'TIP', 'FEE', 'STREAM', 'POLL', 'DONT_LIKE_THIS', 'DONATION', 'BILLING')))::BIGINT as msats_spent
FROM generate_series(min, max, ival) period(t)
LEFT JOIN
((SELECT "userId", msats as quantity, act::TEXT as type, created_at
FROM "ItemAct"
WHERE created_at >= min_utc
AND ("ItemAct"."invoiceActionState" IS NULL OR "ItemAct"."invoiceActionState" = 'PAID'))
UNION ALL
(SELECT "userId", sats*1000 as quantity, 'DONATION' as type, created_at
FROM "Donation"
WHERE created_at >= min_utc)
UNION ALL
(SELECT "userId", 1 as quantity,
CASE WHEN "Item"."parentId" IS NULL THEN 'POST' ELSE 'COMMENT' END as type, created_at
FROM "Item"
WHERE created_at >= min_utc)
UNION ALL
(SELECT "referrerId" as "userId", 1 as quantity, 'REFERRAL' as type, created_at
FROM users
WHERE "referrerId" IS NOT NULL
AND created_at >= min_utc)
UNION ALL
-- tips accounting for forwarding
(SELECT "Item"."userId", floor("ItemAct".msats * (1-COALESCE(sum("ItemForward".pct)/100.0, 0))) as quantity, 'TIPPEE' as type, "ItemAct".created_at
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
LEFT JOIN "ItemForward" on "ItemForward"."itemId" = "Item".id
WHERE "ItemAct".act = 'TIP'
AND "ItemAct".created_at >= min_utc
AND ("ItemAct"."invoiceActionState" IS NULL OR "ItemAct"."invoiceActionState" = 'PAID')
GROUP BY "Item"."userId", "ItemAct".id, "ItemAct".msats, "ItemAct".created_at)
UNION ALL
-- tips where stacker is a forwardee
(SELECT "ItemForward"."userId", floor("ItemAct".msats*("ItemForward".pct/100.0)) as quantity, 'TIPPEE' as type, "ItemAct".created_at
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
JOIN "ItemForward" on "ItemForward"."itemId" = "Item".id
WHERE "ItemAct".act = 'TIP'
AND "ItemAct".created_at >= min_utc
AND ("ItemAct"."invoiceActionState" IS NULL OR "ItemAct"."invoiceActionState" = 'PAID'))
UNION ALL
(SELECT "userId", msats as quantity, 'EARN' as type, created_at
FROM "Earn"
WHERE (type is NULL OR type NOT IN ('FOREVER_REFERRAL', 'ONE_DAY_REFERRAL'))
AND created_at >= min_utc)
UNION ALL
(SELECT "userId", msats as quantity, type::TEXT as type, created_at
FROM "Earn"
WHERE type IN ('FOREVER_REFERRAL', 'ONE_DAY_REFERRAL')
AND created_at >= min_utc)
UNION ALL
(SELECT "referrerId" as "userId", msats as quantity, 'REFERRAL_ACT' as type, created_at
FROM "ReferralAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT "userId", msats as quantity, type::TEXT as type, created_at
FROM "SubAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT "userId", 1 as quantity, 'TERRITORY' as type, created_at
FROM "Sub"
WHERE status <> 'STOPPED'
AND created_at >= min_utc)
UNION ALL
-- for every referree, get the one day referrer on each day
(SELECT mode() WITHIN GROUP (ORDER BY "OneDayReferral"."referrerId") AS "userId", 1 as quantity,
'ONE_DAY_REFERRAL_COUNT' as type, max(created_at) AS created_at
FROM "OneDayReferral"
WHERE created_at >= min_utc
GROUP BY "refereeId", date_trunc('day', created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')
HAVING mode() WITHIN GROUP (ORDER BY "OneDayReferral"."referrerId") IS NOT NULL)
) u ON period.t = date_trunc(date_part, u.created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')
GROUP BY "userId", period.t
ORDER BY period.t ASC;
END;
$$;
DROP MATERIALIZED VIEW IF EXISTS user_stats_hours;
CREATE MATERIALIZED VIEW IF NOT EXISTS user_stats_hours AS
SELECT (user_stats(min, max, '1 hour'::INTERVAL, 'hour')).* FROM last_24_hours;
DROP MATERIALIZED VIEW IF EXISTS user_stats_days;
CREATE MATERIALIZED VIEW IF NOT EXISTS user_stats_days AS
SELECT (user_stats(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days;
DROP MATERIALIZED VIEW IF EXISTS user_stats_months;
CREATE MATERIALIZED VIEW IF NOT EXISTS user_stats_months AS
SELECT (user_stats(min, max, '1 month'::INTERVAL, 'month')).* FROM all_months;
CREATE UNIQUE INDEX IF NOT EXISTS user_stats_months_idx ON user_stats_months(t, id);
CREATE UNIQUE INDEX IF NOT EXISTS user_stats_days_idx ON user_stats_days(t, id);
CREATE UNIQUE INDEX IF NOT EXISTS user_stats_hours_idx ON user_stats_hours(t, id);
DROP FUNCTION IF EXISTS earn(user_id INTEGER, earn_msats BIGINT, created_at TIMESTAMP(3),
type "EarnType", type_id INTEGER, rank INTEGER);
CREATE OR REPLACE FUNCTION stacking_growth(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (t TIMESTAMP(3), rewards BIGINT, posts BIGINT, comments BIGINT, referrals BIGINT, territories BIGINT)
LANGUAGE plpgsql
AS $$
DECLARE
min_utc TIMESTAMP(3) := timezone('utc', min AT TIME ZONE 'America/Chicago');
BEGIN
RETURN QUERY
SELECT period.t,
coalesce(floor(sum(airdrop)/1000),0)::BIGINT as rewards,
coalesce(floor(sum(post)/1000),0)::BIGINT as posts,
coalesce(floor(sum(comment)/1000),0)::BIGINT as comments,
coalesce(floor(sum(referral)/1000),0)::BIGINT as referrals,
coalesce(floor(sum(revenue)/1000),0)::BIGINT as territories
FROM generate_series(min, max, ival) period(t)
LEFT JOIN
((SELECT "ItemAct".created_at, 0 as airdrop,
CASE WHEN "Item"."parentId" IS NULL THEN 0 ELSE "ItemAct".msats END as comment,
CASE WHEN "Item"."parentId" IS NULL THEN "ItemAct".msats ELSE 0 END as post,
0 as referral,
0 as revenue
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
WHERE "ItemAct".act = 'TIP'
AND "ItemAct".created_at >= min_utc
AND ("ItemAct"."invoiceActionState" IS NULL OR "ItemAct"."invoiceActionState" = 'PAID'))
UNION ALL
(SELECT created_at, 0 as airdrop, 0 as post, 0 as comment, msats as referral, 0 as revenue
FROM "ReferralAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, msats as airdrop, 0 as post, 0 as comment, 0 as referral, 0 as revenue
FROM "Earn"
WHERE ("Earn".type is NULL OR "Earn".type NOT IN ('FOREVER_REFERRAL', 'ONE_DAY_REFERRAL'))
AND created_at >= min_utc)
UNION ALL
(SELECT created_at, 0 as airdrop, 0 as post, 0 as comment, msats as referral, 0 as revenue
FROM "Earn"
WHERE "Earn".type IN ('FOREVER_REFERRAL', 'ONE_DAY_REFERRAL')
AND created_at >= min_utc)
UNION ALL
(SELECT created_at, 0 as airdrop, 0 as post, 0 as comment, 0 as referral, msats as revenue
FROM "SubAct"
WHERE type = 'REVENUE'
AND created_at >= min_utc)
) u ON period.t = date_trunc(date_part, u.created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')
GROUP BY period.t
ORDER BY period.t ASC;
END;
$$;
CREATE OR REPLACE FUNCTION stackers_growth(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (t TIMESTAMP(3), "userId" INT, type TEXT)
LANGUAGE plpgsql
AS $$
DECLARE
min_utc TIMESTAMP(3) := timezone('utc', min AT TIME ZONE 'America/Chicago');
BEGIN
RETURN QUERY
SELECT period.t, u."userId", u.type
FROM generate_series(min, max, ival) period(t)
LEFT JOIN
((SELECT "ItemAct".created_at, "Item"."userId", CASE WHEN "Item"."parentId" IS NULL THEN 'POST' ELSE 'COMMENT' END as type
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
WHERE "ItemAct".act = 'TIP'
AND "ItemAct".created_at >= min_utc
AND ("ItemAct"."invoiceActionState" IS NULL OR "ItemAct"."invoiceActionState" = 'PAID'))
UNION ALL
(SELECT created_at, "Earn"."userId", 'EARN' as type
FROM "Earn"
WHERE ("Earn".type is NULL OR "Earn".type NOT IN ('FOREVER_REFERRAL', 'ONE_DAY_REFERRAL'))
AND created_at >= min_utc)
UNION ALL
(SELECT created_at, "ReferralAct"."referrerId" as "userId", 'REFERRAL' as type
FROM "ReferralAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, "Earn"."userId", 'REFERRAL' as type
FROM "Earn"
WHERE "Earn".type IN ('FOREVER_REFERRAL', 'ONE_DAY_REFERRAL')
AND created_at >= min_utc)
UNION ALL
(SELECT created_at, "SubAct"."userId", 'REVENUE' as type
FROM "SubAct"
WHERE "SubAct".type = 'REVENUE'
AND created_at >= min_utc)
) u ON period.t = date_trunc(date_part, u.created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')
GROUP BY period.t, u."userId", u.type
ORDER BY period.t ASC;
END;
$$;

View File

@ -1011,6 +1011,8 @@ enum EarnType {
COMMENT
TIP_COMMENT
TIP_POST
FOREVER_REFERRAL
ONE_DAY_REFERRAL
}
enum SubActType {

1
svgs/service-fill.svg Normal file
View File

@ -0,0 +1 @@
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 24 24" fill="currentColor"><path d="M14.1213 10.4792C13.7308 10.0886 13.0976 10.0886 12.7071 10.4792L12 11.1863C11.2189 11.9673 9.95259 11.9673 9.17154 11.1863C8.39049 10.4052 8.39049 9.13888 9.17154 8.35783L14.8022 2.72568C16.9061 2.24973 19.2008 2.83075 20.8388 4.46875C23.2582 6.88811 23.3716 10.7402 21.1792 13.2939L19.071 15.4289L14.1213 10.4792ZM3.16113 4.46875C5.33452 2.29536 8.66411 1.98283 11.17 3.53116L7.75732 6.94362C6.19523 8.50572 6.19523 11.0384 7.75732 12.6005C9.27209 14.1152 11.6995 14.1611 13.2695 12.7382L13.4142 12.6005L17.6568 16.8431L13.4142 21.0858C12.6331 21.8668 11.3668 21.8668 10.5858 21.0858L3.16113 13.6611C0.622722 11.1227 0.622722 7.00715 3.16113 4.46875Z"></path></svg>

After

Width:  |  Height:  |  Size: 756 B

1
svgs/user-add-fill.svg Normal file
View File

@ -0,0 +1 @@
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 24 24" fill="currentColor"><path d="M14 14.252V22H4C4 17.5817 7.58172 14 12 14C12.6906 14 13.3608 14.0875 14 14.252ZM12 13C8.685 13 6 10.315 6 7C6 3.685 8.685 1 12 1C15.315 1 18 3.685 18 7C18 10.315 15.315 13 12 13ZM18 17V14H20V17H23V19H20V22H18V19H15V17H18Z"></path></svg>

After

Width:  |  Height:  |  Size: 326 B

View File

@ -1,4 +1,3 @@
import serialize from '@/api/resolvers/serial.js'
import { notifyEarner } from '@/lib/webPush.js'
import { PrismaClient } from '@prisma/client'
import { proportions } from '@/lib/madness.js'
@ -20,7 +19,8 @@ export async function earn ({ name }) {
// 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
// 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')
@ -48,55 +48,90 @@ export async function earn ({ name }) {
- how early they upvoted it
- how the post/comment scored
Now: 100% of earnings go to top 33% of comments/posts and their upvoters for month
Now: 80% of earnings go to top 100 stackers by value, and 10% each to their forever and one day referrers
*/
// get earners { userId, id, type, rank, proportion }
// get earners { userId, id, type, rank, proportion, foreverReferrerId, oneDayReferrerId }
const earners = await models.$queryRaw`
SELECT id AS "userId", proportion, ROW_NUMBER() OVER (ORDER BY proportion DESC) as rank
FROM user_values(date_trunc('day', now() AT TIME ZONE 'America/Chicago' - interval '1 day'), date_trunc('day', now() AT TIME ZONE 'America/Chicago' - interval '1 day'), '1 day'::INTERVAL, 'day')
WHERE NOT (id = ANY (${SN_NO_REWARDS_IDS}))
ORDER BY proportion DESC
LIMIT 100`
WITH earners AS (
SELECT users.id AS "userId", users."referrerId" AS "foreverReferrerId",
proportion, (ROW_NUMBER() OVER (ORDER BY proportion DESC))::INTEGER AS rank
FROM user_values(
date_trunc('day', now() AT TIME ZONE 'America/Chicago' - interval '1 day'),
date_trunc('day', now() AT TIME ZONE 'America/Chicago' - interval '1 day'),
'1 day'::INTERVAL,
'day') uv
JOIN users ON users.id = uv.id
WHERE NOT (users.id = ANY (${SN_NO_REWARDS_IDS}))
ORDER BY proportion DESC
LIMIT 100
)
SELECT earners.*,
COALESCE(
mode() WITHIN GROUP (ORDER BY "OneDayReferral"."referrerId"),
earners."foreverReferrerId") AS "oneDayReferrerId"
FROM earners
LEFT JOIN "OneDayReferral" ON "OneDayReferral"."refereeId" = earners."userId"
WHERE "OneDayReferral".created_at >= date_trunc('day', now() AT TIME ZONE 'America/Chicago' - interval '1 day')
GROUP BY earners."userId", earners."foreverReferrerId", earners.proportion, earners.rank
ORDER BY rank ASC`
// in order to group earnings for users we use the same createdAt time for
// all earnings
const now = new Date(new Date().getTime())
const createdAt = new Date(new Date().getTime())
// stmts is an array of prisma promises we'll call after the loop
const stmts = []
// this is just a sanity check because it seems like a good idea
let total = 0
const notifications = {}
for (const [i, earner] of earners.entries()) {
const earnings = Math.floor(parseFloat(proportions[i] * sum))
total += earnings
const foreverReferrerEarnings = Math.floor(parseFloat(earner.proportion * sum * 0.1)) // 10% of earnings
let oneDayReferrerEarnings = Math.floor(parseFloat(earner.proportion * sum * 0.1)) // 10% of earnings
const earnerEarnings = Math.floor(parseFloat(proportions[i] * sum)) - foreverReferrerEarnings - oneDayReferrerEarnings
total += earnerEarnings + foreverReferrerEarnings + oneDayReferrerEarnings
if (total > sum) {
console.log(name, 'total exceeds sum', total, '>', sum)
return
}
console.log('stacker', earner.userId, 'earned', earnings, 'proportion', earner.proportion, 'rank', earner.rank, 'type', earner.type)
console.log(
'stacker', earner.userId,
'earned', earnerEarnings,
'proportion', earner.proportion,
'rank', earner.rank,
'type', earner.type,
'foreverReferrer', earner.foreverReferrerId,
'foreverReferrerEarnings', foreverReferrerEarnings,
'oneDayReferrer', earner.oneDayReferrerId,
'oneDayReferrerEarnings', oneDayReferrerEarnings)
if (earnings > 0) {
await serialize(
models.$executeRaw`SELECT earn(${earner.userId}::INTEGER, ${earnings},
${now}::timestamp without time zone, ${earner.type}::"EarnType", ${earner.id}::INTEGER, ${earner.rank}::INTEGER)`,
{ models }
)
if (earnerEarnings > 0) {
stmts.push(...earnStmts({
msats: earnerEarnings,
userId: earner.userId,
createdAt,
type: earner.type,
rank: earner.rank
}, { models }))
const userN = notifications[earner.userId] || {}
// sum total
const prevMsats = userN.msats || 0
const msats = earnings + prevMsats
const msats = earnerEarnings + prevMsats
// sum total per earn type (POST, COMMENT, TIP_COMMENT, TIP_POST)
const prevEarnTypeMsats = userN[earner.type]?.msats || 0
const earnTypeMsats = earnings + prevEarnTypeMsats
const earnTypeMsats = earnerEarnings + prevEarnTypeMsats
// best (=lowest) rank per earn type
const prevEarnTypeBestRank = userN[earner.type]?.bestRank
const earnTypeBestRank = prevEarnTypeBestRank ? Math.min(prevEarnTypeBestRank, Number(earner.rank)) : Number(earner.rank)
const earnTypeBestRank = prevEarnTypeBestRank
? Math.min(prevEarnTypeBestRank, Number(earner.rank))
: Number(earner.rank)
notifications[earner.userId] = {
...userN,
@ -104,8 +139,34 @@ export async function earn ({ name }) {
[earner.type]: { msats: earnTypeMsats, bestRank: earnTypeBestRank }
}
}
if (earner.foreverReferrerId && foreverReferrerEarnings > 0) {
stmts.push(...earnStmts({
msats: foreverReferrerEarnings,
userId: earner.foreverReferrerId,
createdAt,
type: 'FOREVER_REFERRAL',
rank: earner.rank
}, { models }))
} else if (earner.oneDayReferrerId) {
// if the person doesn't have a forever referrer yet, they give double to their one day referrer
oneDayReferrerEarnings += foreverReferrerEarnings
}
if (earner.oneDayReferrerId && oneDayReferrerEarnings > 0) {
stmts.push(...earnStmts({
msats: oneDayReferrerEarnings,
userId: earner.oneDayReferrerId,
createdAt,
type: 'ONE_DAY_REFERRAL',
rank: earner.rank
}, { models }))
}
}
// execute all the transactions
await models.$transaction(stmts)
Promise.allSettled(
Object.entries(notifications).map(([userId, earnings]) => notifyEarner(parseInt(userId, 10), earnings))
).catch(console.error)
@ -113,3 +174,16 @@ export async function earn ({ name }) {
models.$disconnect().catch(console.error)
}
}
function earnStmts (data, { models }) {
const { msats, userId } = data
return [
models.earn.create({ data }),
models.user.update({
where: { id: userId },
data: {
msats: { increment: msats },
stackedMsats: { increment: msats }
}
})]
}