fix territory revenue attribution for one founder and multiple terrtories
This commit is contained in:
parent
7a942881ed
commit
a73ac8896e
|
@ -0,0 +1,28 @@
|
||||||
|
-- fix revenue for users who have multiple revenue entries for the same day
|
||||||
|
WITH revenue_days AS (
|
||||||
|
SELECT coalesce(sum(msats), 0) as revenue_msats, "userId", created_at
|
||||||
|
FROM "SubAct"
|
||||||
|
WHERE type = 'REVENUE'
|
||||||
|
GROUP BY "userId", created_at
|
||||||
|
HAVING COUNT(*) > 1
|
||||||
|
),
|
||||||
|
revenue_total AS (
|
||||||
|
SELECT coalesce(sum(revenue_msats), 0) as revenue_msats, "userId"
|
||||||
|
FROM revenue_days
|
||||||
|
GROUP BY "userId"
|
||||||
|
)
|
||||||
|
UPDATE users SET msats = users.msats + revenue_total.revenue_msats
|
||||||
|
FROM revenue_total
|
||||||
|
WHERE users.id = revenue_total."userId";
|
||||||
|
|
||||||
|
-- fix stacked msats for users who have territory revenue
|
||||||
|
-- prior to this, we were not updating stacked msats for territory revenue
|
||||||
|
WITH territory_revenue AS (
|
||||||
|
SELECT coalesce(sum(msats), 0) as revenue_msats, "userId"
|
||||||
|
FROM "SubAct"
|
||||||
|
WHERE type = 'REVENUE'
|
||||||
|
GROUP BY "userId"
|
||||||
|
)
|
||||||
|
UPDATE users SET "stackedMsats" = users."stackedMsats" + territory_revenue.revenue_msats
|
||||||
|
FROM territory_revenue
|
||||||
|
WHERE users.id = territory_revenue."userId";
|
|
@ -72,10 +72,17 @@ export async function territoryRevenue ({ models }) {
|
||||||
FROM revenue
|
FROM revenue
|
||||||
WHERE revenue > 1000
|
WHERE revenue > 1000
|
||||||
RETURNING *
|
RETURNING *
|
||||||
|
),
|
||||||
|
"SubActResultTotal" AS (
|
||||||
|
SELECT coalesce(sum(msats), 0) as total_msats, "userId"
|
||||||
|
FROM "SubActResult"
|
||||||
|
GROUP BY "userId"
|
||||||
)
|
)
|
||||||
UPDATE users SET msats = users.msats + "SubActResult".msats
|
UPDATE users
|
||||||
FROM "SubActResult"
|
SET msats = users.msats + "SubActResultTotal".total_msats,
|
||||||
WHERE users.id = "SubActResult"."userId"`,
|
"stackedMsats" = users."stackedMsats" + "SubActResultTotal".total_msats
|
||||||
|
FROM "SubActResultTotal"
|
||||||
|
WHERE users.id = "SubActResultTotal"."userId"`,
|
||||||
{ models }
|
{ models }
|
||||||
)
|
)
|
||||||
}
|
}
|
||||||
|
|
Loading…
Reference in New Issue