denormalize replies (#958)

This commit is contained in:
Keyan 2024-03-23 23:15:00 -05:00 committed by GitHub
parent e565e74e2d
commit a7b0272200
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
4 changed files with 138 additions and 30 deletions

View File

@ -78,14 +78,13 @@ export default {
itemDrivenQueries.push(
`SELECT "Item".*, "Item".created_at AS "sortTime", 'Reply' AS type
FROM "ThreadSubscription"
JOIN "Item" p ON "ThreadSubscription"."itemId" = p.id
JOIN "Item" ON ${meFull.noteAllDescendants ? '"Item".path <@ p.path' : '"Item"."parentId" = p.id'}
JOIN "Reply" r ON "ThreadSubscription"."itemId" = r."ancestorId"
JOIN "Item" ON r."itemId" = "Item".id
${whereClause(
'"ThreadSubscription"."userId" = $1',
'"Item"."userId" <> $1',
'"Item".created_at >= "ThreadSubscription".created_at',
'"Item".created_at < $2',
'"Item"."parentId" IS NOT NULL'
'r.created_at >= "ThreadSubscription".created_at',
'r.created_at < $2',
...(meFull.noteAllDescendants ? [] : ['r.level = 1'])
)}
ORDER BY "sortTime" DESC
LIMIT ${LIMIT}`

View File

@ -237,15 +237,15 @@ export default {
SELECT EXISTS(
SELECT *
FROM "ThreadSubscription"
JOIN "Item" p ON "ThreadSubscription"."itemId" = p.id
JOIN "Item" ON ${user.noteAllDescendants ? '"Item".path <@ p.path' : '"Item"."parentId" = p.id'}
JOIN "Reply" r ON "ThreadSubscription"."itemId" = r."ancestorId"
JOIN "Item" ON r."itemId" = "Item".id
${whereClause(
'"ThreadSubscription"."userId" = $1',
'"Item".created_at > $2',
'"Item".created_at >= "ThreadSubscription".created_at',
'"Item"."userId" <> $1',
'r.created_at > $2',
'r.created_at >= "ThreadSubscription".created_at',
await filterClause(me, models),
muteClause(me)
muteClause(me),
...(user.noteAllDescendants ? [] : ['r.level = 1'])
)})`, me.id, lastChecked)
if (newThreadSubReply.exists) {
foundNotes()

View File

@ -0,0 +1,83 @@
-- CreateTable
CREATE TABLE "Reply" (
"id" SERIAL NOT NULL,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"ancestorId" INTEGER NOT NULL,
"ancestorUserId" INTEGER NOT NULL,
"itemId" INTEGER NOT NULL,
"userId" INTEGER NOT NULL,
"level" INTEGER NOT NULL,
CONSTRAINT "Reply_pkey" PRIMARY KEY ("id")
);
-- CreateIndex
CREATE INDEX "Reply_ancestorId_idx" ON "Reply"("ancestorId");
-- CreateIndex
CREATE INDEX "Reply_ancestorUserId_idx" ON "Reply"("ancestorUserId");
-- CreateIndex
CREATE INDEX "Reply_level_idx" ON "Reply"("level");
-- CreateIndex
CREATE INDEX "Reply_created_at_idx" ON "Reply"("created_at");
-- AddForeignKey
ALTER TABLE "Reply" ADD CONSTRAINT "Reply_userId_fkey" FOREIGN KEY ("userId") REFERENCES "users"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "Reply" ADD CONSTRAINT "Reply_itemId_fkey" FOREIGN KEY ("itemId") REFERENCES "Item"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "Reply" ADD CONSTRAINT "Reply_ancestorUserId_fkey" FOREIGN KEY ("ancestorUserId") REFERENCES "users"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
-- AddForeignKey
ALTER TABLE "Reply" ADD CONSTRAINT "Reply_ancestorId_fkey" FOREIGN KEY ("ancestorId") REFERENCES "Item"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
CREATE OR REPLACE FUNCTION ncomments_after_comment() RETURNS TRIGGER AS $$
DECLARE
user_trust DOUBLE PRECISION;
BEGIN
-- grab user's trust who is commenting
SELECT trust INTO user_trust FROM users WHERE id = NEW."userId";
UPDATE "Item"
SET "lastCommentAt" = now_utc(), "ncomments" = "ncomments" + 1
WHERE id <> NEW.id and path @> NEW.path;
-- we only want to add the user's trust to weightedComments if they aren't
-- already the author of a descendant comment
UPDATE "Item"
SET "weightedComments" = "weightedComments" + user_trust
FROM (
-- for every ancestor of the new comment, return the ones that don't have
-- the same author in their descendants
SELECT p.id
FROM "Item" p
-- all decendants of p that aren't the new comment
JOIN "Item" c ON c.path <@ p.path AND c.id <> NEW.id
-- p is an ancestor of this comment, it isn't itself, and it doesn't have the same author
WHERE p.path @> NEW.path AND p.id <> NEW.id AND p."userId" <> NEW."userId"
GROUP BY p.id
-- only return p if it doesn't have any descendants with the same author as the comment
HAVING bool_and(c."userId" <> NEW."userId")
) fresh
WHERE "Item".id = fresh.id;
-- insert the comment into the reply table for every ancestor
INSERT INTO "Reply" (created_at, updated_at, "ancestorId", "ancestorUserId", "itemId", "userId", level)
SELECT NEW.created_at, NEW.updated_at, p.id, p."userId", NEW.id, NEW."userId", nlevel(NEW.path) - nlevel(p.path)
FROM "Item" p
WHERE p.path @> NEW.path AND p.id <> NEW.id AND p."userId" <> NEW."userId";
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- insert the comment into the reply table for every ancestor retroactively
INSERT INTO "Reply" (created_at, updated_at, "ancestorId", "ancestorUserId", "itemId", "userId", level)
SELECT c.created_at, c.created_at, p.id, p."userId", c.id, c."userId", nlevel(c.path) - nlevel(p.path)
FROM "Item" p
JOIN "Item" c ON c.path <@ p.path AND c.id <> p.id AND p."userId" <> c."userId";

View File

@ -26,7 +26,7 @@ model User {
checkedNotesAt DateTime?
foundNotesAt DateTime?
pubkey String? @unique(map: "users.pubkey_unique")
apiKey String? @db.Char(32) @unique(map: "users.apikey_unique")
apiKey String? @unique(map: "users.apikey_unique") @db.Char(32)
apiKeyEnabled Boolean @default(false)
tipDefault Int @default(100)
bioId Int?
@ -119,6 +119,8 @@ model User {
Wallet Wallet[]
TerritoryTransfers TerritoryTransfer[] @relation("TerritoryTransfer_oldUser")
TerritoryReceives TerritoryTransfer[] @relation("TerritoryTransfer_newUser")
AncestorReplies Reply[] @relation("AncestorReplyUser")
Replies Reply[]
@@index([photoId])
@@index([createdAt], map: "users.created_at_index")
@ -387,6 +389,8 @@ model Item {
uploadId Int?
outlawed Boolean @default(false)
pollExpiresAt DateTime?
Ancestors Reply[] @relation("AncestorReplyItem")
Replies Reply[]
@@index([uploadId])
@@index([bio], map: "Item.bio_index")
@ -406,6 +410,28 @@ model Item {
@@index([weightedVotes], map: "Item.weightedVotes_index")
}
// this is a denomalized table that is used to make reply notifications
// more efficient ... it is populated by a trigger when replies are created
model Reply {
id Int @id @default(autoincrement())
createdAt DateTime @default(now()) @map("created_at")
updatedAt DateTime @default(now()) @updatedAt @map("updated_at")
ancestorId Int
ancestorUserId Int
itemId Int
userId Int
level Int
User User @relation(fields: [userId], references: [id])
Item Item @relation(fields: [itemId], references: [id])
AncestorUser User @relation("AncestorReplyUser", fields: [ancestorUserId], references: [id])
AncestorItem Item @relation("AncestorReplyItem", fields: [ancestorId], references: [id])
@@index([ancestorId])
@@index([ancestorUserId])
@@index([level])
@@index([createdAt])
}
// TODO: make all Item's forward 100% of sats to the OP by default
// so that forwards aren't a special case everywhere
model ItemForward {