denormalize stacked count

This commit is contained in:
keyan 2022-04-04 16:54:31 -05:00
parent becc69250e
commit c284e18278
3 changed files with 94 additions and 29 deletions

View File

@ -154,23 +154,8 @@ export default {
if (user.stacked) {
return user.stacked
}
const [{ sum }] = await models.$queryRaw`
SELECT sum("ItemAct".sats)
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
WHERE "ItemAct"."userId" <> ${user.id} AND "ItemAct".act <> 'BOOST'
AND "Item"."userId" = ${user.id}`
const { sum: { msats } } = await models.earn.aggregate({
sum: {
msats: true
},
where: {
userId: Number(user.id)
}
})
return (sum || 0) + Math.floor((msats || 0) / 1000)
return Math.floor((user.stackedMsats || 0) / 1000)
},
sats: async (user, args, { models, me }) => {
if (me?.id !== user.id) {
@ -189,15 +174,16 @@ export default {
},
hasNewNotes: async (user, args, { models }) => {
// check if any votes have been cast for them since checkedNotesAt
const lastChecked = user.checkedNotesAt || new Date(0)
const votes = await models.$queryRaw(`
SELECT "ItemAct".id, "ItemAct".created_at
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
FROM "Item"
JOIN "ItemAct" on "ItemAct"."itemId" = "Item".id
WHERE "ItemAct"."userId" <> $1
AND ("ItemAct".created_at > $2 OR $2 IS NULL)
AND "ItemAct".created_at > $2
AND "ItemAct".act <> 'BOOST'
AND "Item"."userId" = $1
LIMIT 1`, user.id, user.checkedNotesAt)
LIMIT 1`, user.id, lastChecked)
if (votes.length > 0) {
return true
}
@ -208,8 +194,8 @@ export default {
FROM "Item"
JOIN "Item" p ON "Item".path <@ p.path
WHERE p."userId" = $1
AND ("Item".created_at > $2 OR $2 IS NULL) AND "Item"."userId" <> $1
LIMIT 1`, user.id, user.checkedNotesAt)
AND "Item".created_at > $2 AND "Item"."userId" <> $1
LIMIT 1`, user.id, lastChecked)
if (newReplies.length > 0) {
return true
}
@ -220,9 +206,9 @@ export default {
FROM "Mention"
JOIN "Item" ON "Mention"."itemId" = "Item".id
WHERE "Mention"."userId" = $1
AND ("Mention".created_at > $2 OR $2 IS NULL)
AND "Mention".created_at > $2
AND "Item"."userId" <> $1
LIMIT 1`, user.id, user.checkedNotesAt)
LIMIT 1`, user.id, lastChecked)
if (newMentions.length > 0) {
return true
}
@ -237,7 +223,7 @@ export default {
},
userId: user.id,
statusUpdatedAt: {
gt: user.checkedNotesAt || new Date(0)
gt: lastChecked
}
}
})
@ -249,7 +235,7 @@ export default {
where: {
userId: user.id,
createdAt: {
gt: user.checkedNotesAt || new Date(0)
gt: lastChecked
},
msats: {
gte: 1000
@ -264,7 +250,7 @@ export default {
where: {
userId: user.id,
confirmedAt: {
gt: user.checkedNotesAt || new Date(0)
gt: lastChecked
}
}
})
@ -277,8 +263,8 @@ export default {
SELECT "Invite".id
FROM users JOIN "Invite" on users."inviteId" = "Invite".id
WHERE "Invite"."userId" = $1
AND (users.created_at > $2 or $2 IS NULL)
LIMIT 1`, user.id, user.checkedNotesAt)
AND users.created_at > $2
LIMIT 1`, user.id, lastChecked)
return newInvitees.length > 0
}
}

View File

@ -0,0 +1,78 @@
-- AlterTable
ALTER TABLE "users" ADD COLUMN "stackedMsats" INTEGER NOT NULL DEFAULT 0;
-- update the stacked value for all users
UPDATE users
SET "stackedMsats" = subquery.stacked
FROM (SELECT users.id, COALESCE(SUM("ItemAct".sats)*1000 + COALESCE((SELECT SUM(msats) FROM "Earn" WHERE "userId" = users.id),0),0) AS stacked
FROM users
LEFT JOIN "Item" ON "Item"."userId" = users.id
LEFT JOIN "ItemAct" ON "ItemAct"."itemId" = "Item".id AND "ItemAct"."userId" <> users.id AND "ItemAct".act <> 'BOOST'
GROUP BY users.id) subquery
WHERE users.id = subquery.id;
-- item_act needs to take into account stacked
CREATE OR REPLACE FUNCTION item_act(item_id INTEGER, user_id INTEGER, act "ItemActType", act_sats INTEGER)
RETURNS INTEGER
LANGUAGE plpgsql
AS $$
DECLARE
user_sats INTEGER;
BEGIN
PERFORM ASSERT_SERIALIZED();
SELECT (msats / 1000) INTO user_sats FROM users WHERE id = user_id;
IF act_sats > user_sats THEN
RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
END IF;
-- deduct sats from actor
UPDATE users SET msats = msats - (act_sats * 1000) WHERE id = user_id;
IF act = 'BOOST' THEN
INSERT INTO "ItemAct" (sats, "itemId", "userId", act, created_at, updated_at)
VALUES (act_sats, item_id, user_id, 'BOOST', now_utc(), now_utc());
ELSE
-- add sats to actee's balance and stacked count
UPDATE users
SET msats = msats + (act_sats * 1000), "stackedMsats" = "stackedMsats" + (act_sats * 1000)
WHERE id = (SELECT "userId" FROM "Item" WHERE id = item_id);
-- if they have already voted, this is a tip
IF EXISTS (SELECT 1 FROM "ItemAct" WHERE "itemId" = item_id AND "userId" = user_id AND "ItemAct".act = 'VOTE') THEN
INSERT INTO "ItemAct" (sats, "itemId", "userId", act, created_at, updated_at)
VALUES (act_sats, item_id, user_id, 'TIP', now_utc(), now_utc());
ELSE
-- else this is a vote with a possible extra tip
INSERT INTO "ItemAct" (sats, "itemId", "userId", act, created_at, updated_at)
VALUES (1, item_id, user_id, 'VOTE', now_utc(), now_utc());
act_sats := act_sats - 1;
-- if we have sats left after vote, leave them as a tip
IF act_sats > 0 THEN
INSERT INTO "ItemAct" (sats, "itemId", "userId", act, created_at, updated_at)
VALUES (act_sats, item_id, user_id, 'TIP', now_utc(), now_utc());
END IF;
RETURN 1;
END IF;
END IF;
RETURN 0;
END;
$$;
-- earn needs to take into account stacked
CREATE OR REPLACE FUNCTION earn(user_id INTEGER, earn_msats INTEGER) RETURNS void AS $$
DECLARE
BEGIN
PERFORM ASSERT_SERIALIZED();
-- insert into earn
INSERT INTO "Earn" (msats, "userId") VALUES (earn_msats, user_id);
-- give the user the sats
UPDATE users
SET msats = msats + earn_msats, "stackedMsats" = "stackedMsats" + earn_msats
WHERE id = user_id;
END;
$$ LANGUAGE plpgsql;

View File

@ -30,6 +30,7 @@ model User {
bio Item? @relation(name: "Item", fields: [bioId], references: [id])
bioId Int?
msats Int @default(0)
stackedMsats Int @default(0)
freeComments Int @default(5)
freePosts Int @default(2)
checkedNotesAt DateTime?