+ }
+
+
)
}
@@ -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}`)
}