From 0b0e36e3cb887fb3716d5f4ff90cfef00a305514 Mon Sep 17 00:00:00 2001 From: Keyan <34140557+huumn@users.noreply.github.com> Date: Fri, 1 Mar 2024 10:28:55 -0600 Subject: [PATCH] Monthly rewards (#890) * show placeholder for hidden stackers in top * top rewardability views * make territory revenue idependent job * monthly rewards and leaderboard on rewards pages * fix earn reschedule * add query for rewards leaderboard * reduce likelihood of rewards racing with views * fix earn and refine values views --- api/resolvers/growth.js | 3 +- api/resolvers/rewards.js | 91 +++++--- api/resolvers/user.js | 103 ++++++--- api/typeDefs/rewards.js | 1 + api/typeDefs/user.js | 9 +- components/footer-rewards.js | 4 +- components/top-header.js | 6 +- components/user-list.js | 103 ++++++--- lib/constants.js | 6 +- lib/madness.js | 66 ++++++ lib/time.js | 12 + pages/rewards/index.js | 216 +++++++++++------- .../migration.sql | 110 +++++++++ .../migration.sql | 16 ++ .../20240229194605_reward_views/migration.sql | 73 ++++++ worker/earn.js | 147 ++---------- worker/index.js | 3 +- worker/territory.js | 32 +++ worker/trust.js | 2 +- worker/views.js | 9 + 20 files changed, 688 insertions(+), 324 deletions(-) create mode 100644 lib/madness.js create mode 100644 prisma/migrations/20240228011144_user_values_view/migration.sql create mode 100644 prisma/migrations/20240229191545_territory_revenue_schedule/migration.sql create mode 100644 prisma/migrations/20240229194605_reward_views/migration.sql diff --git a/api/resolvers/growth.js b/api/resolvers/growth.js index 5b320272..4e36cbd1 100644 --- a/api/resolvers/growth.js +++ b/api/resolvers/growth.js @@ -42,7 +42,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))) + WHERE "${view}".t >= date_trunc('${unit}', timezone('America/Chicago', $1)) + AND "${view}".t <= date_trunc('${unit}', timezone('America/Chicago', $2))) ) u` } diff --git a/api/resolvers/rewards.js b/api/resolvers/rewards.js index 79231d5c..32fbeb8d 100644 --- a/api/resolvers/rewards.js +++ b/api/resolvers/rewards.js @@ -3,23 +3,50 @@ import { amountSchema, ssValidate } from '../../lib/validate' import { serializeInvoicable } from './serial' import { ANON_USER_ID } from '../../lib/constants' import { getItem } from './item' +import { topUsers } from './user' -const rewardCache = new Map() +let rewardCache -async function updateCachedRewards (when, models) { - const rewards = await getRewards(when, models) - rewardCache.set(when, { rewards, createdAt: Date.now() }) +async function updateCachedRewards (models) { + const rewards = await getActiveRewards(models) + rewardCache = { rewards, createdAt: Date.now() } return rewards } -async function getCachedRewards (staleIn, when, models) { - if (rewardCache.has(when)) { - const { rewards, createdAt } = rewardCache.get(when) +async function getCachedActiveRewards (staleIn, models) { + if (rewardCache) { + const { rewards, createdAt } = rewardCache const expired = createdAt + staleIn < Date.now() - if (expired) updateCachedRewards(when, models).catch(console.error) + if (expired) updateCachedRewards(models).catch(console.error) return rewards // serve stale rewards } - return await updateCachedRewards(when, models) + return await updateCachedRewards(models) +} + +async function getActiveRewards (models) { + return await models.$queryRaw` + SELECT + (sum(total) / 1000)::INT as total, + date_trunc('month', (now() AT TIME ZONE 'America/Chicago') + interval '1 month') AT TIME ZONE 'America/Chicago' as time, + json_build_array( + json_build_object('name', 'donations', 'value', (sum(donations) / 1000)::INT), + json_build_object('name', 'fees', 'value', (sum(fees) / 1000)::INT), + json_build_object('name', 'boost', 'value', (sum(boost) / 1000)::INT), + json_build_object('name', 'jobs', 'value', (sum(jobs) / 1000)::INT), + json_build_object('name', 'anon''s stack', 'value', (sum(anons_stack) / 1000)::INT) + ) AS sources + FROM ( + (SELECT * + FROM rewards_days + WHERE rewards_days.t >= date_trunc('month', now() AT TIME ZONE 'America/Chicago')) + UNION ALL + (SELECT * FROM rewards_today) + UNION ALL + (SELECT * FROM + rewards( + date_trunc('hour', timezone('America/Chicago', now())), + date_trunc('hour', timezone('America/Chicago', now())), '1 hour'::INTERVAL, 'hour')) + ) u` } async function getRewards (when, models) { @@ -45,37 +72,18 @@ async function getRewards (when, models) { COALESCE(${when?.[when.length - 1]}::text::timestamp - interval '1 day', now() AT TIME ZONE 'America/Chicago'), interval '1 day') AS t ) - SELECT coalesce(FLOOR(sum(sats)), 0) as total, + SELECT (total / 1000)::INT as total, days_cte.day + interval '1 day' as time, json_build_array( - json_build_object('name', 'donations', 'value', coalesce(FLOOR(sum(sats) FILTER(WHERE type = 'DONATION')), 0)), - json_build_object('name', 'fees', 'value', coalesce(FLOOR(sum(sats) FILTER(WHERE type NOT IN ('BOOST', 'STREAM', 'DONATION', 'ANON'))), 0)), - json_build_object('name', 'boost', 'value', coalesce(FLOOR(sum(sats) FILTER(WHERE type = 'BOOST')), 0)), - json_build_object('name', 'jobs', 'value', coalesce(FLOOR(sum(sats) FILTER(WHERE type = 'STREAM')), 0)), - json_build_object('name', 'anon''s stack', 'value', coalesce(FLOOR(sum(sats) FILTER(WHERE type = 'ANON')), 0)) + json_build_object('name', 'donations', 'value', donations / 1000), + json_build_object('name', 'fees', 'value', fees / 1000), + json_build_object('name', 'boost', 'value', boost / 1000), + json_build_object('name', 'jobs', 'value', jobs / 1000), + json_build_object('name', 'anon''s stack', 'value', anons_stack / 1000) ) AS sources FROM days_cte - CROSS JOIN LATERAL ( - (SELECT ("ItemAct".msats - COALESCE("ReferralAct".msats, 0)) / 1000.0 as sats, act::text as type - 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') = days_cte.day AND "ItemAct".act <> 'TIP') - UNION ALL - (SELECT sats::FLOAT, 'DONATION' as type - FROM "Donation" - WHERE date_trunc('day', created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = days_cte.day) - UNION ALL - -- any earnings from anon's stack that are not forwarded to other users - (SELECT "ItemAct".msats / 1000.0 as sats, 'ANON' as type - FROM "Item" - JOIN "ItemAct" ON "ItemAct"."itemId" = "Item".id - LEFT JOIN "ItemForward" ON "ItemForward"."itemId" = "Item".id - WHERE "Item"."userId" = ${ANON_USER_ID} AND "ItemAct".act = 'TIP' - AND date_trunc('day', "ItemAct".created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = days_cte.day - GROUP BY "ItemAct".id, "ItemAct".msats - HAVING COUNT("ItemForward".id) = 0) - ) subquery - GROUP BY days_cte.day + JOIN rewards_days ON rewards_days.t = days_cte.day + GROUP BY days_cte.day, total, donations, fees, boost, jobs, anons_stack ORDER BY days_cte.day ASC` return results.length ? results : [{ total: 0, time: '0', sources: [] }] @@ -84,7 +92,7 @@ async function getRewards (when, models) { export default { Query: { rewards: async (parent, { when }, { models }) => - when ? await getRewards(when, models) : await getCachedRewards(5000, when, models), + when ? await getRewards(when, models) : await getCachedActiveRewards(5000, models), meRewards: async (parent, { when }, { me, models }) => { if (!me) { return null @@ -122,6 +130,15 @@ export default { return results } }, + Rewards: { + leaderboard: async (parent, args, { models, ...context }) => { + // get to and from using postgres because it's easier to do there + const [{ to, from }] = await models.$queryRaw` + SELECT date_trunc('month', (now() AT TIME ZONE 'America/Chicago')) AT TIME ZONE 'America/Chicago' as from, + (date_trunc('month', (now() AT TIME ZONE 'America/Chicago')) AT TIME ZONE 'America/Chicago') + interval '1 month - 1 second' as to` + return await topUsers(parent, { when: 'custom', to: new Date(to).getTime().toString(), from: new Date(from).getTime().toString(), limit: 64 }, { models, ...context }) + } + }, Mutation: { donateToRewards: async (parent, { sats, hash, hmac }, { me, models, lnd }) => { await ssValidate(amountSchema, { amount: sats }) diff --git a/api/resolvers/user.js b/api/resolvers/user.js index 73517b6a..0b6b5ff9 100644 --- a/api/resolvers/user.js +++ b/api/resolvers/user.js @@ -5,7 +5,7 @@ import { decodeCursor, LIMIT, nextCursorEncoded } from '../../lib/cursor' import { msatsToSats } from '../../lib/format' import { bioSchema, emailSchema, settingsSchema, ssValidate, userSchema } from '../../lib/validate' import { getItem, updateItem, filterClause, createItem, whereClause, muteClause } from './item' -import { ANON_USER_ID, DELETE_USER_ID, RESERVED_MAX_USER_ID } from '../../lib/constants' +import { ANON_USER_ID, DELETE_USER_ID, RESERVED_MAX_USER_ID, SN_USER_IDS } from '../../lib/constants' import { viewGroup } from './growth' import { whenRange } from '../../lib/time' @@ -50,6 +50,65 @@ async function authMethods (user, args, { models, me }) { } } +export async function topUsers (parent, { cursor, when, by, from, to, limit = LIMIT }, { models, me }) { + const decodedCursor = decodeCursor(cursor) + const range = whenRange(when, from, to || decodeCursor.time) + + let column + switch (by) { + case 'spent': column = 'spent'; break + case 'posts': column = 'nposts'; break + case 'comments': column = 'ncomments'; break + case 'referrals': column = 'referrals'; break + case 'stacking': column = 'stacked'; break + default: column = 'proportion'; break + } + + const users = (await models.$queryRawUnsafe(` + SELECT * + FROM + (SELECT users.*, + COALESCE(floor(sum(msats_spent)/1000), 0) as spent, + COALESCE(sum(posts), 0) as nposts, + COALESCE(sum(comments), 0) as ncomments, + COALESCE(sum(referrals), 0) as referrals, + COALESCE(floor(sum(msats_stacked)/1000), 0) as stacked + FROM ${viewGroup(range, 'user_stats')} + JOIN users on users.id = u.id + GROUP BY users.id) uu + ${column === 'proportion' ? `JOIN ${viewValueGroup()} ON uu.id = vv.id` : ''} + ORDER BY ${column} DESC NULLS LAST, uu.created_at ASC + OFFSET $3 + LIMIT $4`, ...range, decodedCursor.offset, limit) + ).map( + u => u.hideFromTopUsers ? null : u + ) + + return { + cursor: users.length === limit ? nextCursorEncoded(decodedCursor, limit) : null, + users + } +} + +export function viewValueGroup () { + return `( + SELECT v.id, sum(proportion) as proportion + FROM ( + (SELECT * + FROM user_values_days + WHERE user_values_days.t >= date_trunc('day', timezone('America/Chicago', $1)) + AND date_trunc('day', user_values_days.t) <= date_trunc('day', timezone('America/Chicago', $2))) + UNION ALL + (SELECT * FROM + user_values_today + WHERE user_values_today.t >= date_trunc('day', timezone('America/Chicago', $1)) + AND date_trunc('day', user_values_today.t) <= date_trunc('day', timezone('America/Chicago', $2))) + ) v + WHERE v.id NOT IN (${SN_USER_IDS.join(',')}) + GROUP BY v.id + ) vv` +} + export default { Query: { me: async (parent, args, { models, me }) => { @@ -82,7 +141,7 @@ export default { const decodedCursor = decodeCursor(cursor) const range = whenRange('forever') - const users = await models.$queryRawUnsafe(` + const users = (await models.$queryRawUnsafe(` SELECT users.*, coalesce(floor(sum(msats_spent)/1000),0) as spent, coalesce(sum(posts),0) as nposts, @@ -91,11 +150,15 @@ export default { coalesce(floor(sum(msats_stacked)/1000),0) as stacked FROM ${viewGroup(range, 'user_stats')} JOIN users on users.id = u.id - WHERE NOT "hideFromTopUsers" AND NOT "hideCowboyHat" AND streak IS NOT NULL + WHERE streak IS NOT NULL GROUP BY users.id ORDER BY streak DESC, created_at ASC OFFSET $3 LIMIT ${LIMIT}`, ...range, decodedCursor.offset) + ).map( + u => u.hideFromTopUsers || u.hideCowboyHat ? null : u + ) + return { cursor: users.length === LIMIT ? nextCursorEncoded(decodedCursor) : null, users @@ -126,39 +189,7 @@ export default { return users }, - topUsers: async (parent, { cursor, when, by, from, to, limit = LIMIT }, { models, me }) => { - const decodedCursor = decodeCursor(cursor) - const range = whenRange(when, from, to || decodeCursor.time) - - let column - switch (by) { - case 'spent': column = 'spent'; break - case 'posts': column = 'nposts'; break - case 'comments': column = 'ncomments'; break - case 'referrals': column = 'referrals'; break - default: column = 'stacked'; break - } - - const users = await models.$queryRawUnsafe(` - SELECT users.*, - COALESCE(floor(sum(msats_spent)/1000), 0) as spent, - COALESCE(sum(posts), 0) as nposts, - COALESCE(sum(comments), 0) as ncomments, - COALESCE(sum(referrals), 0) as referrals, - COALESCE(floor(sum(msats_stacked)/1000), 0) as stacked - FROM ${viewGroup(range, 'user_stats')} - JOIN users on users.id = u.id - WHERE NOT users."hideFromTopUsers" - GROUP BY users.id - ORDER BY ${column} DESC NULLS LAST, users.created_at ASC - OFFSET $3 - LIMIT $4`, ...range, decodedCursor.offset, limit) - - return { - cursor: users.length === limit ? nextCursorEncoded(decodedCursor, limit) : null, - users - } - }, + topUsers, hasNewNotes: async (parent, args, { me, models }) => { if (!me) { return false diff --git a/api/typeDefs/rewards.js b/api/typeDefs/rewards.js index 90feb30f..0ce0df2a 100644 --- a/api/typeDefs/rewards.js +++ b/api/typeDefs/rewards.js @@ -14,6 +14,7 @@ export default gql` total: Int! time: Date! sources: [NameValue!]! + leaderboard: UsersNullable } type Reward { diff --git a/api/typeDefs/user.js b/api/typeDefs/user.js index 8b808a51..aa054913 100644 --- a/api/typeDefs/user.js +++ b/api/typeDefs/user.js @@ -7,13 +7,18 @@ export default gql` user(name: String!): User users: [User!] nameAvailable(name: String!): Boolean! - topUsers(cursor: String, when: String, from: String, to: String, by: String, limit: Limit): Users - topCowboys(cursor: String): Users + topUsers(cursor: String, when: String, from: String, to: String, by: String, limit: Limit): UsersNullable! + topCowboys(cursor: String): UsersNullable! searchUsers(q: String!, limit: Limit, similarity: Float): [User!]! userSuggestions(q: String, limit: Limit): [User!]! hasNewNotes: Boolean! } + type UsersNullable { + cursor: String + users: [User]! + } + type Users { cursor: String users: [User!]! diff --git a/components/footer-rewards.js b/components/footer-rewards.js index a00e2ba9..91b6cee4 100644 --- a/components/footer-rewards.js +++ b/components/footer-rewards.js @@ -7,15 +7,17 @@ const REWARDS = gql` { rewards { total + time } }` export default function Rewards () { const { data } = useQuery(REWARDS, SSR ? { ssr: false } : { pollInterval: 60000, nextFetchPolicy: 'cache-and-network' }) const total = data?.rewards?.[0]?.total + const time = data?.rewards?.[0]?.time return ( - {total ? : 'rewards'} + {total ? : 'rewards'} ) } diff --git a/components/top-header.js b/components/top-header.js index 0f74aaa1..f49ea285 100644 --- a/components/top-header.js +++ b/components/top-header.js @@ -20,8 +20,8 @@ export default function TopHeader ({ sub, cat }) { if (typeof query.by !== 'undefined') { if (query.by === '' || - (what === 'stackers' && (query.by === 'stacked' || !USER_SORTS.includes(query.by))) || - (what === 'territories' && (query.by === 'stacked' || !SUB_SORTS.includes(query.by))) || + (what === 'stackers' && (query.by === 'value' || !USER_SORTS.includes(query.by))) || + (what === 'territories' && (query.by === 'stacking' || !SUB_SORTS.includes(query.by))) || (['posts', 'comments'].includes(what) && (query.by === 'zaprank' || !ITEM_SORTS.includes(query.by)))) { delete query.by } @@ -36,7 +36,7 @@ export default function TopHeader ({ sub, cat }) { } const what = cat - const by = router.query.by || (what === 'stackers' ? 'stacked' : 'zaprank') + const by = router.query.by || (what === 'stackers' ? 'value' : what === 'territories' ? 'stacking' : 'zaprank') const when = router.query.when || '' return ( diff --git a/components/user-list.js b/components/user-list.js index ead4fd32..fca1ad89 100644 --- a/components/user-list.js +++ b/components/user-list.js @@ -36,7 +36,76 @@ function seperate (arr, seperator) { return arr.flatMap((x, i) => i < arr.length - 1 ? [x, seperator] : [x]) } -export default function UserList ({ ssrData, query, variables, destructureData, rank }) { +function User ({ user, rank, statComps, Embellish }) { + return ( + <> + {rank + ? ( +
+ {rank} +
) + :
} +
+ + + +
+ + @{user.name} + +
+ {statComps.map((Comp, i) => )} +
+ {Embellish && } +
+
+ + ) +} + +function UserHidden ({ rank, Embellish }) { + return ( + <> + {rank + ? ( +
+ {rank} +
) + :
} +
+ + + +
+
+ stacker is in hiding +
+ {Embellish && } +
+
+ + ) +} + +export function ListUsers ({ users, rank, statComps = seperate(STAT_COMPONENTS, Seperator), Embellish }) { + return ( +
+ {users.map((user, i) => ( + user + ? + : + ))} +
+ ) +} + +export default function UserList ({ ssrData, query, variables, destructureData, rank, footer = true }) { const { data, fetchMore } = useQuery(query, { variables }) const dat = useData(data, ssrData) const [statComps, setStatComps] = useState(seperate(STAT_COMPONENTS, Seperator)) @@ -62,35 +131,9 @@ export default function UserList ({ ssrData, query, variables, destructureData, return ( <> -
- {users?.map((user, i) => ( - - {rank - ? ( -
- {i + 1} -
) - :
} -
- - - -
- - @{user.name} - -
- {statComps.map((Comp, i) => )} -
-
-
- - ))} -
- + + {footer && + } ) } diff --git a/lib/constants.js b/lib/constants.js index 0331aa53..5c3d6826 100644 --- a/lib/constants.js +++ b/lib/constants.js @@ -33,7 +33,7 @@ export const ITEM_SPAM_INTERVAL = '10m' export const ANON_ITEM_SPAM_INTERVAL = '0' export const INV_PENDING_LIMIT = 100 export const BALANCE_LIMIT_MSATS = 250000000 // 250k sat -export const SN_USER_IDS = [616, 6030, 946, 4502] +export const SN_USER_IDS = [616, 6030, 946, 4502, 27] export const ANON_INV_PENDING_LIMIT = 1000 export const ANON_BALANCE_LIMIT_MSATS = 0 // disable export const MAX_POLL_NUM_CHOICES = 10 @@ -42,9 +42,9 @@ export const POLL_COST = 1 export const ITEM_FILTER_THRESHOLD = 1.2 export const DONT_LIKE_THIS_COST = 1 export const COMMENT_TYPE_QUERY = ['comments', 'freebies', 'outlawed', 'borderland', 'all', 'bookmarks'] -export const USER_SORTS = ['stacked', 'spent', 'comments', 'posts', 'referrals'] +export const USER_SORTS = ['value', 'stacking', 'spending', 'comments', 'posts', 'referrals'] export const ITEM_SORTS = ['zaprank', 'comments', 'sats'] -export const SUB_SORTS = ['stacked', 'revenue', 'spent', 'posts', 'comments'] +export const SUB_SORTS = ['stacking', 'revenue', 'spending', 'posts', 'comments'] export const WHENS = ['day', 'week', 'month', 'year', 'forever', 'custom'] export const ITEM_TYPES_USER = ['all', 'posts', 'comments', 'bounties', 'links', 'discussions', 'polls', 'freebies', 'jobs', 'bookmarks'] export const ITEM_TYPES = ['all', 'posts', 'comments', 'bounties', 'links', 'discussions', 'polls', 'freebies', 'bios', 'jobs'] diff --git a/lib/madness.js b/lib/madness.js new file mode 100644 index 00000000..2be505cb --- /dev/null +++ b/lib/madness.js @@ -0,0 +1,66 @@ +export const proportions = [ + 0.3312903760145768, + 0.09938711280437303, + 0.06625807520291535, + 0.04969355640218651, + 0.033129037601457675, + 0.02981613384131191, + 0.026503230081166142, + 0.023190326321020374, + 0.019877422560874606, + 0.016564518800728838, + 0.014908066920655955, + 0.013251615040583071, + 0.012920324664568494, + 0.012589034288553918, + 0.01225774391253934, + 0.011926453536524764, + 0.011595163160510187, + 0.01126387278449561, + 0.010932582408481033, + 0.010601292032466457, + 0.01027000165645188, + 0.009938711280437303, + 0.009607420904422726, + 0.00927613052840815, + 0.008944840152393572, + 0.008613549776378996, + 0.008282259400364419, + 0.007950969024349842, + 0.007619678648335266, + 0.007288388272320689, + 0.006957097896306112, + 0.006625807520291536, + 0.006294517144276959, + 0.005963226768262382, + 0.005631936392247805, + 0.005300646016233228, + 0.0049693556402186515, + 0.004638065264204075, + 0.004306774888189498, + 0.003975484512174921, + 0.0036441941361603446, + 0.003312903760145768, + 0.0031472585721384794, + 0.002981613384131191, + 0.0028159681961239026, + 0.002650323008116614, + 0.0024846778201093257, + 0.0023190326321020373, + 0.002153387444094749, + 0.0019877422560874605, + 0.0018220970680801723, + 0.001656451880072884, + 0.0014908066920655955, + 0.001325161504058307, + 0.0011595163160510187, + 0.0009938711280437303, + 0.000828225940036442, + 0.0006625807520291535, + 0.0004969355640218651, + 0.00033129037601457677, + 0.00033129037601457677, + 0.00033129037601457677, + 0.00033129037601457677, + 0.00033129037601457677 +] diff --git a/lib/time.js b/lib/time.js index 1ccdcca3..fdc41a0f 100644 --- a/lib/time.js +++ b/lib/time.js @@ -115,3 +115,15 @@ export const whenToFrom = (when) => { } export const sleep = (ms) => new Promise((resolve, reject) => setTimeout(resolve, ms)) + +export function dateToTimeZone (date, tz) { + return date.getTime() + tzOffset(tz) * 60 * 60 * 1000 +} + +function tzOffset (tz) { + const date = new Date() + date.setMilliseconds(0) + const targetDate = new Date(date.toLocaleString('en-US', { timeZone: tz })) + const targetOffsetHours = (date.getTime() - targetDate.getTime()) / 1000 / 60 / 60 + return targetOffsetHours +} diff --git a/pages/rewards/index.js b/pages/rewards/index.js index eb72a82f..e940e5ab 100644 --- a/pages/rewards/index.js +++ b/pages/rewards/index.js @@ -1,10 +1,9 @@ import { gql } from 'graphql-tag' -import { useMemo } from 'react' import Button from 'react-bootstrap/Button' import InputGroup from 'react-bootstrap/InputGroup' import { getGetServerSideProps } from '../../api/ssrApollo' import { Form, Input, SubmitButton } from '../../components/form' -import { CenterLayout } from '../../components/layout' +import Layout from '../../components/layout' import { useMutation, useQuery } from '@apollo/client' import Link from 'next/link' import { amountSchema } from '../../lib/validate' @@ -16,15 +15,48 @@ import dynamic from 'next/dynamic' import { SSR } from '../../lib/constants' import { useToast } from '../../components/toast' import { useLightning } from '../../components/lightning' +import { ListUsers } from '../../components/user-list' +import { Col, Row } from 'react-bootstrap' +import { proportions } from '../../lib/madness' const GrowthPieChart = dynamic(() => import('../../components/charts').then(mod => mod.GrowthPieChart), { loading: () =>
Loading...
}) +const REWARDS_FULL = gql` +{ + rewards { + total + time + sources { + name + value + } + leaderboard { + users { + id + name + photoId + ncomments(when: $when, from: $from, to: $to) + nposts(when: $when, from: $from, to: $to) + + optional { + streak + stacked(when: $when, from: $from, to: $to) + spent(when: $when, from: $from, to: $to) + referrals(when: $when, from: $from, to: $to) + } + } + } + } +} +` + const REWARDS = gql` { rewards { total + time sources { name value @@ -33,58 +65,82 @@ const REWARDS = gql` } ` -function midnight (tz) { - function tzOffset (tz) { - const date = new Date() - date.setMilliseconds(0) - const targetDate = new Date(date.toLocaleString('en-US', { timeZone: tz })) - const targetOffsetHours = (date.getTime() - targetDate.getTime()) / 1000 / 60 / 60 - return targetOffsetHours - } - - const date = new Date() - date.setHours(24, 0, 0, 0) - return date.getTime() + tzOffset(tz) * 60 * 60 * 1000 -} - -export const getServerSideProps = getGetServerSideProps({ query: REWARDS }) - -export function RewardLine ({ total }) { - const threshold = useMemo(() => midnight('America/Chicago')) +export const getServerSideProps = getGetServerSideProps({ query: REWARDS_FULL }) +export function RewardLine ({ total, time }) { return ( <> - {numWithUnits(total)} in rewards - {threshold && + + {numWithUnits(total)} in rewards + + {time && {props.formatted.hours}:{props.formatted.minutes}:{props.formatted.seconds}} + date={time} + renderer={props => + + {props.formatted.days + ? ` ${props.formatted.days}d ${props.formatted.hours}h ${props.formatted.minutes}m ${props.formatted.seconds}s` + : ` ${props.formatted.hours}:${props.formatted.minutes}:${props.formatted.seconds}`} + } />} ) } export default function Rewards ({ ssrData }) { - const { data } = useQuery(REWARDS, SSR ? {} : { pollInterval: 1000, nextFetchPolicy: 'cache-and-network' }) + // only poll for updates to rewards and not leaderboard + const { data } = useQuery( + REWARDS, + SSR ? {} : { pollInterval: 1000, nextFetchPolicy: 'cache-and-network' }) if (!data && !ssrData) return - const { rewards: [{ total, sources }] } = data || ssrData + let { rewards: [{ total, sources, time, leaderboard }] } = ssrData + if (data?.rewards?.length > 0) { + total = data.rewards[0].total + sources = data.rewards[0].sources + time = data.rewards[0].time + } + + function EstimatedReward ({ rank }) { + return ( +
+ + estimated reward: {numWithUnits(Math.floor(total * proportions[rank - 1]))} + +
+ ) + } return ( - -

-
- -
- - learn about rewards - -

-
- -
- -
+ + + +
+

+
+ +
+ + learn about rewards + +

+
+ +
+ +
+ + {leaderboard?.users && + +

leaderboard

+
+ +
+ } +
+
) } @@ -100,46 +156,48 @@ export function DonateButton () { return ( <> - diff --git a/prisma/migrations/20240228011144_user_values_view/migration.sql b/prisma/migrations/20240228011144_user_values_view/migration.sql new file mode 100644 index 00000000..f1afbcab --- /dev/null +++ b/prisma/migrations/20240228011144_user_values_view/migration.sql @@ -0,0 +1,110 @@ +CREATE INDEX IF NOT EXISTS "ItemAct.created_at_hour_index" + ON "ItemAct"(date_trunc('hour', 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')); +CREATE INDEX IF NOT EXISTS "Item.created_at_day_index" + ON "Item"(date_trunc('day', created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')); +CREATE INDEX IF NOT EXISTS "Donation.created_at_hour_index" + ON "Donation"(date_trunc('hour', created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')); +CREATE INDEX IF NOT EXISTS "Item.created_at_hour_index" + ON "Item"(date_trunc('hour', created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')); + +CREATE OR REPLACE FUNCTION user_values( + min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT, + percentile_cutoff INTEGER DEFAULT 33, + each_upvote_portion FLOAT DEFAULT 4.0, + each_item_portion FLOAT DEFAULT 4.0, + handicap_ids INTEGER[] DEFAULT '{616, 6030, 946, 4502}', + handicap_zap_mult FLOAT DEFAULT 0.2) +RETURNS TABLE ( + t TIMESTAMP(3), id INTEGER, proportion FLOAT +) +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.total_proportion + FROM generate_series(min, max, ival) period(t), + LATERAL + (WITH item_ratios AS ( + 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"-"weightedDownVotes") desc) AS percentile, + ROW_NUMBER() OVER (PARTITION BY "parentId" IS NULL ORDER BY ("weightedVotes"-"weightedDownVotes") desc) AS rank + FROM + "Item" + WHERE date_trunc(date_part, created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = period.t + AND "weightedVotes" > 0 AND "deletedAt" IS NULL AND NOT bio + ) x + WHERE x.percentile <= percentile_cutoff + ), + -- 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' AND date_trunc(date_part, "ItemAct".created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = period.t + ), + -- 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 not disproportionately reward them + upvoters AS ( + SELECT "userId", upvoter_islands.id, ratio, "parentId", GREATEST(log(sum(tipped) / 1000), 0) as tipped, min(acted_at) as acted_at + FROM upvoter_islands + GROUP BY "userId", upvoter_islands.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*CASE WHEN users.id = ANY (handicap_ids) THEN handicap_zap_mult ELSE FLOOR(users.trust*3)+handicap_zap_mult 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 *, + 10.0/LN(ROW_NUMBER() OVER (partition by upvoters.id order by acted_at asc) + EXP(1.0)) AS early_multiplier, + tipped::float/(sum(tipped) OVER (partition by upvoters.id)) tipped_ratio + FROM upvoters + WHERE tipped > 0 + ) u + JOIN users on "userId" = users.id + GROUP BY "userId", "parentId" IS NULL + ), + proportions AS ( + 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"))/each_upvote_portion as proportion + FROM upvoter_ratios + WHERE upvoter_ratio > 0 + UNION ALL + SELECT "userId", item_ratios.id, type, rank, ratio/each_item_portion as proportion + FROM item_ratios + ) + SELECT "userId", sum(proportions.proportion) AS total_proportion + FROM proportions + GROUP BY "userId" + HAVING sum(proportions.proportion) > 0.000001) u; +END; +$$; + +CREATE OR REPLACE VIEW today AS + SELECT date_trunc('day', timezone('America/Chicago', now())) as min, + date_trunc('day', timezone('America/Chicago', now())) as max; + +DROP MATERIALIZED VIEW IF EXISTS user_values_today; +CREATE MATERIALIZED VIEW IF NOT EXISTS user_values_today AS +SELECT (user_values(min, max, '1 day'::INTERVAL, 'day')).* FROM today; + +CREATE UNIQUE INDEX IF NOT EXISTS user_values_today_idx ON user_values_today(id); +CREATE INDEX IF NOT EXISTS user_values_today_proportion_idx ON user_values_today(proportion DESC); + +DROP MATERIALIZED VIEW IF EXISTS user_values_days; +CREATE MATERIALIZED VIEW IF NOT EXISTS user_values_days AS +SELECT (user_values(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days; + +CREATE UNIQUE INDEX IF NOT EXISTS user_values_days_idx ON user_values_days(t, id); \ No newline at end of file diff --git a/prisma/migrations/20240229191545_territory_revenue_schedule/migration.sql b/prisma/migrations/20240229191545_territory_revenue_schedule/migration.sql new file mode 100644 index 00000000..989a324d --- /dev/null +++ b/prisma/migrations/20240229191545_territory_revenue_schedule/migration.sql @@ -0,0 +1,16 @@ +CREATE OR REPLACE FUNCTION schedule_territory_revenue() +RETURNS INTEGER +LANGUAGE plpgsql +AS $$ +DECLARE +BEGIN + INSERT INTO pgboss.schedule (name, cron, timezone) + VALUES ('territoryRevenue', '0 0 * * *', 'America/Chicago') ON CONFLICT DO NOTHING; + return 0; +EXCEPTION WHEN OTHERS THEN + return 0; +END; +$$; + +SELECT schedule_territory_revenue(); +DROP FUNCTION IF EXISTS create_territory_billing_job; diff --git a/prisma/migrations/20240229194605_reward_views/migration.sql b/prisma/migrations/20240229194605_reward_views/migration.sql new file mode 100644 index 00000000..1c301625 --- /dev/null +++ b/prisma/migrations/20240229194605_reward_views/migration.sql @@ -0,0 +1,73 @@ +CREATE OR REPLACE FUNCTION rewards(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT) +RETURNS TABLE ( + t TIMESTAMP(3), total BIGINT, donations BIGINT, fees BIGINT, boost BIGINT, jobs BIGINT, anons_stack BIGINT +) +LANGUAGE plpgsql +AS $$ +DECLARE +BEGIN + RETURN QUERY + SELECT period.t, + coalesce(FLOOR(sum(msats)), 0)::BIGINT as total, + coalesce(FLOOR(sum(msats) FILTER(WHERE type = 'DONATION')), 0)::BIGINT as donations, + coalesce(FLOOR(sum(msats) FILTER(WHERE type NOT IN ('BOOST', 'STREAM', 'DONATION', 'ANON'))), 0)::BIGINT as fees, + coalesce(FLOOR(sum(msats) FILTER(WHERE type = 'BOOST')), 0)::BIGINT as boost, + coalesce(FLOOR(sum(msats) FILTER(WHERE type = 'STREAM')), 0)::BIGINT as jobs, + coalesce(FLOOR(sum(msats) FILTER(WHERE type = 'ANON')), 0)::BIGINT as anons_stack + FROM generate_series(min, max, ival) period(t), + LATERAL + ( + (SELECT + ("ItemAct".msats - COALESCE("ReferralAct".msats, 0)) * COALESCE("Sub"."rewardsPct", 100) * 0.01 as msats, + act::text as type + FROM "ItemAct" + JOIN "Item" ON "Item"."id" = "ItemAct"."itemId" + LEFT JOIN "Sub" ON "Sub"."name" = "Item"."subName" + LEFT JOIN "ReferralAct" ON "ReferralAct"."itemActId" = "ItemAct".id + WHERE date_trunc(date_part, "ItemAct".created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = period.t + AND "ItemAct".act <> 'TIP') + UNION ALL + (SELECT sats * 1000 as msats, 'DONATION' as type + FROM "Donation" + WHERE date_trunc(date_part, "Donation".created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = period.t) + UNION ALL + -- any earnings from anon's stack that are not forwarded to other users + (SELECT "ItemAct".msats, 'ANON' as type + FROM "Item" + JOIN "ItemAct" ON "ItemAct"."itemId" = "Item".id + LEFT JOIN "ItemForward" ON "ItemForward"."itemId" = "Item".id + WHERE "Item"."userId" = 27 AND "ItemAct".act = 'TIP' + AND date_trunc(date_part, "ItemAct".created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago') = period.t + GROUP BY "ItemAct".id, "ItemAct".msats + HAVING COUNT("ItemForward".id) = 0) + ) x + GROUP BY period.t; +END; +$$; + +DROP MATERIALIZED VIEW IF EXISTS rewards_today; +CREATE MATERIALIZED VIEW IF NOT EXISTS rewards_today AS +SELECT (rewards(min, max, '1 day'::INTERVAL, 'day')).* FROM today; + +DROP MATERIALIZED VIEW IF EXISTS rewards_days; +CREATE MATERIALIZED VIEW IF NOT EXISTS rewards_days AS +SELECT (rewards(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days; + +CREATE UNIQUE INDEX IF NOT EXISTS rewards_today_idx ON rewards_today(t); +CREATE UNIQUE INDEX IF NOT EXISTS rewards_days_idx ON rewards_days(t); + +CREATE OR REPLACE FUNCTION reschedule_earn_job() +RETURNS INTEGER +LANGUAGE plpgsql +AS $$ +DECLARE +BEGIN + UPDATE pgboss.schedule set cron = '10 0 1 * *' WHERE name = 'earn'; + return 0; +EXCEPTION WHEN OTHERS THEN + return 0; +END; +$$; + +SELECT reschedule_earn_job(); +DROP FUNCTION IF EXISTS reschedule_earn_job; \ No newline at end of file diff --git a/worker/earn.js b/worker/earn.js index 025bf3a9..05d32e93 100644 --- a/worker/earn.js +++ b/worker/earn.js @@ -1,49 +1,22 @@ import serialize from '../api/resolvers/serial.js' import { sendUserNotification } from '../api/webPush/index.js' -import { ANON_USER_ID, SN_USER_IDS } from '../lib/constants.js' import { msatsToSats, numWithUnits } from '../lib/format.js' import { PrismaClient } from '@prisma/client' +import { proportions } from '../lib/madness.js' +import { SN_USER_IDS } from '../lib/constants.js' -const ITEM_EACH_REWARD = 4.0 -const UPVOTE_EACH_REWARD = 4.0 -const TOP_PERCENTILE = 33 -const TOTAL_UPPER_BOUND_MSATS = 1000000000 +const TOTAL_UPPER_BOUND_MSATS = 10000000000 export async function earn ({ name }) { - // rewards are calculated sitewide still - // however for user gen subs currently only 50% of their fees go to rewards - // the other 50% goes to the founder of the sub - // grab a greedy connection const models = new PrismaClient() try { - // compute how much sn earned today + // compute how much sn earned got the month const [{ sum: sumDecimal }] = await models.$queryRaw` - SELECT coalesce(sum(msats), 0) as sum - FROM ( - (SELECT ("ItemAct".msats - COALESCE("ReferralAct".msats, 0)) * COALESCE("Sub"."rewardsPct", 100) * 0.01 as msats - FROM "ItemAct" - JOIN "Item" ON "Item"."id" = "ItemAct"."itemId" - LEFT JOIN "Sub" ON "Sub"."name" = "Item"."subName" - 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')) - UNION ALL - -- any earnings from anon's stack that are not forwarded to other users - (SELECT "ItemAct".msats - FROM "Item" - JOIN "ItemAct" ON "ItemAct"."itemId" = "Item".id - LEFT JOIN "ItemForward" ON "ItemForward"."itemId" = "Item".id - WHERE "Item"."userId" = ${ANON_USER_ID} AND "ItemAct".act = 'TIP' - AND 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') - GROUP BY "ItemAct".id, "ItemAct".msats - HAVING COUNT("ItemForward".id) = 0) - ) subquery` + SELECT coalesce(sum(total), 0) as sum + FROM rewards_days + WHERE date_trunc('month', rewards_days.t) = date_trunc('month', (now() - interval '1 month') AT TIME ZONE 'America/Chicago')` // 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) @@ -75,70 +48,18 @@ 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 + Now: 100% of earnings go to top 33% of comments/posts and their upvoters for month */ // get earners { userId, id, type, rank, proportion } const earners = await models.$queryRaw` - -- get top 33% of posts and comments - WITH item_ratios AS ( - 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"-"weightedDownVotes") desc) AS percentile, - ROW_NUMBER() OVER (PARTITION BY "parentId" IS NULL ORDER BY ("weightedVotes"-"weightedDownVotes") desc) AS rank - FROM - "Item" - WHERE created_at >= now_utc() - interval '36 hours' - AND "weightedVotes" > 0 AND "deletedAt" IS NULL AND NOT bio - ) x - WHERE x.percentile <= ${TOP_PERCENTILE} - ), - -- 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 not disproporionately reward them - upvoters AS ( - SELECT "userId", id, ratio, "parentId", GREATEST(log(sum(tipped) / 1000), 0) 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*CASE WHEN users.id = ANY (${SN_USER_IDS}) THEN 0.2 ELSE CEIL(users.trust*2)+1 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 *, - 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 - JOIN users on "userId" = users.id - GROUP BY "userId", "parentId" IS NULL - ), - proportions AS ( - 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) - SELECT "userId", id, type, rank, proportion - FROM proportions - WHERE proportion > 0.000001` + SELECT id AS "userId", sum(proportion) as proportion + FROM user_values_days + WHERE date_trunc('month', user_values_days.t) = date_trunc('month', (now() - interval '1 month') AT TIME ZONE 'America/Chicago') + AND NOT (id = ANY (${SN_USER_IDS})) + GROUP BY id + ORDER BY proportion DESC + LIMIT 64` // in order to group earnings for users we use the same createdAt time for // all earnings @@ -148,8 +69,8 @@ export async function earn ({ name }) { let total = 0 const notifications = {} - for (const earner of earners) { - const earnings = Math.floor(parseFloat(earner.proportion) * sum) + for (const [i, earner] of earners.entries()) { + const earnings = Math.floor(parseFloat(proportions[i] * sum)) total += earnings if (total > sum) { console.log(name, 'total exceeds sum', total, '>', sum) @@ -185,8 +106,6 @@ export async function earn ({ name }) { } } - await territoryRevenue({ models }) - Promise.allSettled(Object.entries(notifications).map(([userId, earnings]) => sendUserNotification(parseInt(userId, 10), buildUserNotification(earnings)) )).catch(console.error) @@ -195,38 +114,6 @@ export async function earn ({ name }) { } } -async function territoryRevenue ({ models }) { - await serialize(models, - models.$executeRaw` - WITH revenue AS ( - SELECT coalesce(sum(msats), 0) as revenue, "subName", "userId" - FROM ( - SELECT ("ItemAct".msats - COALESCE("ReferralAct".msats, 0)) * (1 - (COALESCE("Sub"."rewardsPct", 100) * 0.01)) as msats, - "Sub"."name" as "subName", "Sub"."userId" as "userId" - FROM "ItemAct" - JOIN "Item" ON "Item"."id" = "ItemAct"."itemId" - LEFT JOIN "Item" root ON "Item"."rootId" = root.id - JOIN "Sub" ON "Sub"."name" = COALESCE(root."subName", "Item"."subName") - 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' - AND "Sub".status <> 'STOPPED' - ) subquery - GROUP BY "subName", "userId" - ), - "SubActResult" AS ( - INSERT INTO "SubAct" (msats, "subName", "userId", type) - SELECT revenue, "subName", "userId", 'REVENUE' - FROM revenue - WHERE revenue > 1000 - RETURNING * - ) - UPDATE users SET msats = users.msats + "SubActResult".msats - FROM "SubActResult" - WHERE users.id = "SubActResult"."userId"` - ) -} - function buildUserNotification (earnings) { const fmt = msats => numWithUnits(msatsToSats(msats, { abbreviate: false })) diff --git a/worker/index.js b/worker/index.js index a7de7eb3..d1cfa395 100644 --- a/worker/index.js +++ b/worker/index.js @@ -20,7 +20,7 @@ import { views, rankViews } from './views.js' import { imgproxy } from './imgproxy.js' import { deleteItem } from './ephemeralItems.js' import { deleteUnusedImages } from './deleteUnusedImages.js' -import { territoryBilling } from './territory.js' +import { territoryBilling, territoryRevenue } from './territory.js' import { ofac } from './ofac.js' import { autoWithdraw } from './autowithdraw.js' @@ -98,6 +98,7 @@ async function work () { await boss.work('deleteItem', jobWrapper(deleteItem)) await boss.work('deleteUnusedImages', jobWrapper(deleteUnusedImages)) await boss.work('territoryBilling', jobWrapper(territoryBilling)) + await boss.work('territoryRevenue', jobWrapper(territoryRevenue)) await boss.work('ofac', jobWrapper(ofac)) console.log('working jobs') diff --git a/worker/territory.js b/worker/territory.js index 70896507..b2533c1d 100644 --- a/worker/territory.js +++ b/worker/territory.js @@ -40,3 +40,35 @@ export async function territoryBilling ({ data: { subName }, boss, models }) { await territoryStatusUpdate() } } + +export async function territoryRevenue ({ models }) { + await serialize(models, + models.$executeRaw` + WITH revenue AS ( + SELECT coalesce(sum(msats), 0) as revenue, "subName", "userId" + FROM ( + SELECT ("ItemAct".msats - COALESCE("ReferralAct".msats, 0)) * (1 - (COALESCE("Sub"."rewardsPct", 100) * 0.01)) as msats, + "Sub"."name" as "subName", "Sub"."userId" as "userId" + FROM "ItemAct" + JOIN "Item" ON "Item"."id" = "ItemAct"."itemId" + LEFT JOIN "Item" root ON "Item"."rootId" = root.id + JOIN "Sub" ON "Sub"."name" = COALESCE(root."subName", "Item"."subName") + 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' + AND "Sub".status <> 'STOPPED' + ) subquery + GROUP BY "subName", "userId" + ), + "SubActResult" AS ( + INSERT INTO "SubAct" (msats, "subName", "userId", type) + SELECT revenue, "subName", "userId", 'REVENUE' + FROM revenue + WHERE revenue > 1000 + RETURNING * + ) + UPDATE users SET msats = users.msats + "SubActResult".msats + FROM "SubActResult" + WHERE users.id = "SubActResult"."userId"` + ) +} diff --git a/worker/trust.js b/worker/trust.js index a63a1bf8..9f9a8d1a 100644 --- a/worker/trust.js +++ b/worker/trust.js @@ -150,7 +150,7 @@ async function getGraph (models) { confidence(before - disagree, b_total - after, ${Z_CONFIDENCE}) ELSE 0 END AS trust FROM user_pair - WHERE b_id <> ANY (${SN_USER_IDS}) + WHERE NOT (b_id = ANY (${SN_USER_IDS})) UNION ALL SELECT a_id AS id, seed_id AS oid, ${MAX_TRUST}::numeric as trust FROM user_pair, unnest(${SN_USER_IDS}::int[]) seed_id diff --git a/worker/views.js b/worker/views.js index ca971d48..99ce219d 100644 --- a/worker/views.js +++ b/worker/views.js @@ -9,6 +9,15 @@ export async function views ({ data: { period } = { period: 'days' } }) { const models = new PrismaClient() try { + // these views are bespoke so we can't use the loop + if (period === 'days') { + await models.$queryRawUnsafe('REFRESH MATERIALIZED VIEW CONCURRENTLY user_values_days') + await models.$queryRawUnsafe('REFRESH MATERIALIZED VIEW CONCURRENTLY rewards_days') + } + if (period === 'hours') { + await models.$queryRawUnsafe('REFRESH MATERIALIZED VIEW CONCURRENTLY user_values_today') + await models.$queryRawUnsafe('REFRESH MATERIALIZED VIEW CONCURRENTLY rewards_today') + } for (const view of viewPrefixes) { await models.$queryRawUnsafe(`REFRESH MATERIALIZED VIEW CONCURRENTLY ${view}_${period}`) }