denormalize last zap on item for notification querying

This commit is contained in:
keyan 2024-03-24 14:16:29 -05:00
parent 2502c176f1
commit edb3dd365c
4 changed files with 64 additions and 43 deletions

View File

@ -184,15 +184,11 @@ export default {
if (meFull.noteItemSats) { if (meFull.noteItemSats) {
queries.push( queries.push(
`(SELECT "Item".id::TEXT, MAX("ItemAct".created_at) AS "sortTime", `(SELECT "Item".id::TEXT, "Item"."lastZapAt" AS "sortTime",
MAX("Item".msats/1000) as "earnedSats", 'Votification' AS type "Item".msats/1000 as "earnedSats", 'Votification' AS type
FROM "Item" FROM "Item"
JOIN "ItemAct" ON "ItemAct"."itemId" = "Item".id WHERE "Item"."userId" = $1
WHERE "ItemAct"."userId" <> $1 AND "Item"."lastZapAt" < $2
AND "ItemAct".created_at < $2
AND "ItemAct".act IN ('TIP', 'FEE')
AND "Item"."userId" = $1
GROUP BY "Item".id
ORDER BY "sortTime" DESC ORDER BY "sortTime" DESC
LIMIT ${LIMIT})` LIMIT ${LIMIT})`
) )
@ -200,16 +196,12 @@ export default {
if (meFull.noteForwardedSats) { if (meFull.noteForwardedSats) {
queries.push( queries.push(
`(SELECT "Item".id::TEXT, MAX("ItemAct".created_at) AS "sortTime", `(SELECT "Item".id::TEXT, "Item"."lastZapAt" AS "sortTime",
MAX("Item".msats / 1000 * "ItemForward".pct / 100) as "earnedSats", 'ForwardedVotification' AS type ("Item".msats / 1000 * "ItemForward".pct / 100) as "earnedSats", 'ForwardedVotification' AS type
FROM "Item" FROM "Item"
JOIN "ItemAct" ON "ItemAct"."itemId" = "Item".id
JOIN "ItemForward" ON "ItemForward"."itemId" = "Item".id AND "ItemForward"."userId" = $1 JOIN "ItemForward" ON "ItemForward"."itemId" = "Item".id AND "ItemForward"."userId" = $1
WHERE "ItemAct"."userId" <> $1 WHERE "Item"."userId" <> $1
AND "Item"."userId" <> $1 AND "Item"."lastZapAt" < $2
AND "ItemAct".created_at < $2
AND "ItemAct".act IN ('TIP')
GROUP BY "Item".id
ORDER BY "sortTime" DESC ORDER BY "sortTime" DESC
LIMIT ${LIMIT})` LIMIT ${LIMIT})`
) )
@ -298,23 +290,11 @@ export default {
LIMIT ${LIMIT})` LIMIT ${LIMIT})`
) )
// we do all this crazy subquery stuff to make 'reward' islands
const notifications = await models.$queryRawUnsafe( const notifications = await models.$queryRawUnsafe(
`SELECT MAX(id) AS id, MAX("sortTime") AS "sortTime", sum("earnedSats") AS "earnedSats", type, `SELECT id, "sortTime", "earnedSats", type,
MIN("sortTime") AS "minSortTime" "sortTime" AS "minSortTime"
FROM FROM
(SELECT *, (${queries.join(' UNION ALL ')}) u
CASE
WHEN type = 'Earn' THEN
ROW_NUMBER() OVER(ORDER BY "sortTime" DESC) -
ROW_NUMBER() OVER(PARTITION BY type = 'Earn' ORDER BY "sortTime" DESC)
ELSE
ROW_NUMBER() OVER(ORDER BY "sortTime" DESC)
END as island
FROM
(${queries.join(' UNION ALL ')}) u
) sub
GROUP BY type, island
ORDER BY "sortTime" DESC ORDER BY "sortTime" DESC
LIMIT ${LIMIT}`, me.id, decodedCursor.time) LIMIT ${LIMIT}`, me.id, decodedCursor.time)

View File

@ -220,12 +220,8 @@ export default {
SELECT EXISTS( SELECT EXISTS(
SELECT * SELECT *
FROM "Item" FROM "Item"
JOIN "ItemAct" ON WHERE "Item"."lastZapAt" > $2
"ItemAct"."itemId" = "Item".id AND "Item"."userId" = $1)`, me.id, lastChecked)
AND "ItemAct"."userId" <> "Item"."userId"
WHERE "ItemAct".created_at > $2
AND "Item"."userId" = $1
AND "ItemAct".act = 'TIP')`, me.id, lastChecked)
if (newSats.exists) { if (newSats.exists) {
foundNotes() foundNotes()
return true return true
@ -296,15 +292,11 @@ export default {
SELECT EXISTS( SELECT EXISTS(
SELECT * SELECT *
FROM "Item" FROM "Item"
JOIN "ItemAct" ON
"ItemAct"."itemId" = "Item".id
AND "ItemAct"."userId" <> "Item"."userId"
JOIN "ItemForward" ON JOIN "ItemForward" ON
"ItemForward"."itemId" = "Item".id "ItemForward"."itemId" = "Item".id
AND "ItemForward"."userId" = $1 AND "ItemForward"."userId" = $1
WHERE "ItemAct".created_at > $2 WHERE "Item"."lastZapAt" > $2
AND "Item"."userId" <> $1 AND "Item"."userId" <> $1)`, me.id, lastChecked)
AND "ItemAct".act = 'TIP')`, me.id, lastChecked)
if (newFwdSats.exists) { if (newFwdSats.exists) {
foundNotes() foundNotes()
return true return true

View File

@ -0,0 +1,45 @@
-- AlterTable
ALTER TABLE "Item" ADD COLUMN "lastZapAt" TIMESTAMP(3);
-- CreateIndex
CREATE INDEX "Item_lastZapAt_idx" ON "Item"("lastZapAt");
-- CreateIndex
CREATE INDEX "Reply_itemId_idx" ON "Reply"("itemId");
-- CreateIndex
CREATE INDEX "Reply_userId_idx" ON "Reply"("userId");
-- when an item is zapped, update the lastZapAt field
CREATE OR REPLACE FUNCTION sats_after_tip(item_id INTEGER, user_id INTEGER, tip_msats BIGINT) RETURNS INTEGER AS $$
DECLARE
item "Item";
BEGIN
SELECT * FROM "Item" WHERE id = item_id INTO item;
IF user_id <> 27 AND item."userId" = user_id THEN
RETURN 0;
END IF;
UPDATE "Item"
SET "msats" = "msats" + tip_msats,
"lastZapAt" = now()
WHERE id = item.id;
UPDATE "Item"
SET "commentMsats" = "commentMsats" + tip_msats
WHERE id <> item.id and path @> item.path;
RETURN 1;
END;
$$ LANGUAGE plpgsql;
-- retrofit the lastZapAt field for all existing items
UPDATE "Item" SET "lastZapAt" = "Zap".at
FROM (
SELECT "ItemAct"."itemId", MAX("ItemAct"."created_at") AS at
FROM "ItemAct"
WHERE "ItemAct".act = 'TIP'
GROUP BY "ItemAct"."itemId"
) AS "Zap"
WHERE "Item"."id" = "Zap"."itemId";

View File

@ -355,6 +355,7 @@ model Item {
paidImgLink Boolean @default(false) paidImgLink Boolean @default(false)
commentMsats BigInt @default(0) commentMsats BigInt @default(0)
lastCommentAt DateTime? lastCommentAt DateTime?
lastZapAt DateTime?
ncomments Int @default(0) ncomments Int @default(0)
msats BigInt @default(0) msats BigInt @default(0)
weightedDownVotes Float @default(0) weightedDownVotes Float @default(0)
@ -393,6 +394,7 @@ model Item {
Replies Reply[] Replies Reply[]
@@index([uploadId]) @@index([uploadId])
@@index([lastZapAt])
@@index([bio], map: "Item.bio_index") @@index([bio], map: "Item.bio_index")
@@index([createdAt], map: "Item.created_at_index") @@index([createdAt], map: "Item.created_at_index")
@@index([freebie], map: "Item.freebie_index") @@index([freebie], map: "Item.freebie_index")
@ -428,6 +430,8 @@ model Reply {
@@index([ancestorId]) @@index([ancestorId])
@@index([ancestorUserId]) @@index([ancestorUserId])
@@index([itemId])
@@index([userId])
@@index([level]) @@index([level])
@@index([createdAt]) @@index([createdAt])
} }