From 6aeeb406234d17a90ff5c4df3af253021da5ebfb Mon Sep 17 00:00:00 2001 From: keyan Date: Thu, 1 Sep 2022 15:28:19 -0500 Subject: [PATCH] denormalize item sats, comment sats, last comment time, and num comments --- .../migration.sql | 86 +++++++++++++++++++ prisma/schema.prisma | 54 +++++++----- 2 files changed, 117 insertions(+), 23 deletions(-) create mode 100644 prisma/migrations/20220831205352_item_and_comment_stats/migration.sql diff --git a/prisma/migrations/20220831205352_item_and_comment_stats/migration.sql b/prisma/migrations/20220831205352_item_and_comment_stats/migration.sql new file mode 100644 index 00000000..e2448fe5 --- /dev/null +++ b/prisma/migrations/20220831205352_item_and_comment_stats/migration.sql @@ -0,0 +1,86 @@ +-- AlterTable +ALTER TABLE "Item" +ADD COLUMN IF NOT EXISTS "commentSats" INTEGER NOT NULL DEFAULT 0, +ADD COLUMN IF NOT EXISTS "lastCommentAt" TIMESTAMP(3), +ADD COLUMN IF NOT EXISTS "ncomments" INTEGER NOT NULL DEFAULT 0, +ADD COLUMN IF NOT EXISTS "sats" INTEGER NOT NULL DEFAULT 0; + +-- denormalize all existing comments +-- for every item, compute the lastest comment time and number of comments +UPDATE "Item" +SET "lastCommentAt" = subquery."lastCommentAt", ncomments = subquery.ncomments +FROM ( + SELECT a.id, MAX(b.created_at) AS "lastCommentAt", COUNT(b.id) AS ncomments + FROM "Item" a + LEFT JOIN "Item" b ON b.path <@ a.path AND a.id <> b.id + GROUP BY a.id) subquery +WHERE "Item".id = subquery.id; + +-- on comment denormalize comment count and time +CREATE OR REPLACE FUNCTION ncomments_after_comment() RETURNS TRIGGER AS $$ +DECLARE +BEGIN + UPDATE "Item" + SET "lastCommentAt" = now_utc(), "ncomments" = "ncomments" + 1 + WHERE id <> NEW.id and path @> NEW.path; + + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +DROP TRIGGER IF EXISTS ncomments_after_comment_trigger ON "Item"; +CREATE TRIGGER ncomments_after_comment_trigger + AFTER INSERT ON "Item" + FOR EACH ROW + EXECUTE PROCEDURE ncomments_after_comment(); + +-- denormalize all existing sats +-- for every item, compute the total sats it has earned +UPDATE "Item" +SET sats = subquery.sats +FROM ( + SELECT a.id, SUM(c.sats) AS sats + FROM "Item" a + JOIN "ItemAct" c ON c."itemId" = a.id AND c."userId" <> a."userId" + WHERE c.act IN ('VOTE', 'TIP') + GROUP BY a.id) subquery +WHERE "Item".id = subquery.id; + +-- denormalize comment sats +UPDATE "Item" +SET "commentSats" = subquery."commentSats" +FROM ( + SELECT a.id, SUM(b.sats) AS "commentSats" + FROM "Item" a + JOIN "Item" b ON b.path <@ a.path AND a.id <> b.id + GROUP BY a.id) subquery +WHERE "Item".id = subquery.id; + +-- on item act denormalize sats and comment sats +CREATE OR REPLACE FUNCTION sats_after_act() RETURNS TRIGGER AS $$ +DECLARE + item "Item"; +BEGIN + SELECT * FROM "Item" WHERE id = NEW."itemId" INTO item; + IF item."userId" = NEW."userId" THEN + RETURN NEW; + END IF; + + UPDATE "Item" + SET "sats" = "sats" + NEW.sats + WHERE id = item.id; + + UPDATE "Item" + SET "commentSats" = "commentSats" + NEW.sats + WHERE id <> item.id and path @> item.path; + + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +DROP TRIGGER IF EXISTS sats_after_act_trigger ON "ItemAct"; +CREATE TRIGGER sats_after_act_trigger + AFTER INSERT ON "ItemAct" + FOR EACH ROW + WHEN (NEW.act = 'VOTE' or NEW.act = 'TIP') + EXECUTE PROCEDURE sats_after_act(); \ No newline at end of file diff --git a/prisma/schema.prisma b/prisma/schema.prisma index 0442bf6f..9b37d95f 100644 --- a/prisma/schema.prisma +++ b/prisma/schema.prisma @@ -147,29 +147,37 @@ enum Status { } model Item { - id Int @id @default(autoincrement()) - createdAt DateTime @default(now()) @map(name: "created_at") - updatedAt DateTime @default(now()) @updatedAt @map(name: "updated_at") - title String? - text String? - url String? - user User @relation("UserItems", fields: [userId], references: [id]) - userId Int - fwdUser User? @relation(name: "FwdItem", fields: [fwdUserId], references: [id]) - fwdUserId Int? - parent Item? @relation("ParentChildren", fields: [parentId], references: [id]) - parentId Int? - children Item[] @relation("ParentChildren") - actions ItemAct[] - mentions Mention[] - path Unsupported("LTREE")? - pin Pin? @relation(fields: [pinId], references: [id]) - pinId Int? - weightedVotes Float @default(0) - boost Int @default(0) - uploadId Int? - upload Upload? - paidImgLink Boolean @default(false) + id Int @id @default(autoincrement()) + createdAt DateTime @default(now()) @map(name: "created_at") + updatedAt DateTime @default(now()) @updatedAt @map(name: "updated_at") + title String? + text String? + url String? + user User @relation("UserItems", fields: [userId], references: [id]) + userId Int + fwdUser User? @relation(name: "FwdItem", fields: [fwdUserId], references: [id]) + fwdUserId Int? + parent Item? @relation("ParentChildren", fields: [parentId], references: [id]) + parentId Int? + children Item[] @relation("ParentChildren") + actions ItemAct[] + mentions Mention[] + path Unsupported("LTREE")? + pin Pin? @relation(fields: [pinId], references: [id]) + pinId Int? + boost Int @default(0) + uploadId Int? + upload Upload? + paidImgLink Boolean @default(false) + + // denormalized self stats + weightedVotes Float @default(0) + sats Int @default(0) + + // denormalized comment stats + ncomments Int @default(0) + commentSats Int @default(0) + lastCommentAt DateTime? // if sub is null, this is the main sub sub Sub? @relation(fields: [subName], references: [name])