denormalize replies (#958)
This commit is contained in:
parent
e565e74e2d
commit
a7b0272200
@ -78,14 +78,13 @@ export default {
|
|||||||
itemDrivenQueries.push(
|
itemDrivenQueries.push(
|
||||||
`SELECT "Item".*, "Item".created_at AS "sortTime", 'Reply' AS type
|
`SELECT "Item".*, "Item".created_at AS "sortTime", 'Reply' AS type
|
||||||
FROM "ThreadSubscription"
|
FROM "ThreadSubscription"
|
||||||
JOIN "Item" p ON "ThreadSubscription"."itemId" = p.id
|
JOIN "Reply" r ON "ThreadSubscription"."itemId" = r."ancestorId"
|
||||||
JOIN "Item" ON ${meFull.noteAllDescendants ? '"Item".path <@ p.path' : '"Item"."parentId" = p.id'}
|
JOIN "Item" ON r."itemId" = "Item".id
|
||||||
${whereClause(
|
${whereClause(
|
||||||
'"ThreadSubscription"."userId" = $1',
|
'"ThreadSubscription"."userId" = $1',
|
||||||
'"Item"."userId" <> $1',
|
'r.created_at >= "ThreadSubscription".created_at',
|
||||||
'"Item".created_at >= "ThreadSubscription".created_at',
|
'r.created_at < $2',
|
||||||
'"Item".created_at < $2',
|
...(meFull.noteAllDescendants ? [] : ['r.level = 1'])
|
||||||
'"Item"."parentId" IS NOT NULL'
|
|
||||||
)}
|
)}
|
||||||
ORDER BY "sortTime" DESC
|
ORDER BY "sortTime" DESC
|
||||||
LIMIT ${LIMIT}`
|
LIMIT ${LIMIT}`
|
||||||
|
@ -237,15 +237,15 @@ export default {
|
|||||||
SELECT EXISTS(
|
SELECT EXISTS(
|
||||||
SELECT *
|
SELECT *
|
||||||
FROM "ThreadSubscription"
|
FROM "ThreadSubscription"
|
||||||
JOIN "Item" p ON "ThreadSubscription"."itemId" = p.id
|
JOIN "Reply" r ON "ThreadSubscription"."itemId" = r."ancestorId"
|
||||||
JOIN "Item" ON ${user.noteAllDescendants ? '"Item".path <@ p.path' : '"Item"."parentId" = p.id'}
|
JOIN "Item" ON r."itemId" = "Item".id
|
||||||
${whereClause(
|
${whereClause(
|
||||||
'"ThreadSubscription"."userId" = $1',
|
'"ThreadSubscription"."userId" = $1',
|
||||||
'"Item".created_at > $2',
|
'r.created_at > $2',
|
||||||
'"Item".created_at >= "ThreadSubscription".created_at',
|
'r.created_at >= "ThreadSubscription".created_at',
|
||||||
'"Item"."userId" <> $1',
|
|
||||||
await filterClause(me, models),
|
await filterClause(me, models),
|
||||||
muteClause(me)
|
muteClause(me),
|
||||||
|
...(user.noteAllDescendants ? [] : ['r.level = 1'])
|
||||||
)})`, me.id, lastChecked)
|
)})`, me.id, lastChecked)
|
||||||
if (newThreadSubReply.exists) {
|
if (newThreadSubReply.exists) {
|
||||||
foundNotes()
|
foundNotes()
|
||||||
|
83
prisma/migrations/20240323222903_replies/migration.sql
Normal file
83
prisma/migrations/20240323222903_replies/migration.sql
Normal 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";
|
@ -26,7 +26,7 @@ model User {
|
|||||||
checkedNotesAt DateTime?
|
checkedNotesAt DateTime?
|
||||||
foundNotesAt DateTime?
|
foundNotesAt DateTime?
|
||||||
pubkey String? @unique(map: "users.pubkey_unique")
|
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)
|
apiKeyEnabled Boolean @default(false)
|
||||||
tipDefault Int @default(100)
|
tipDefault Int @default(100)
|
||||||
bioId Int?
|
bioId Int?
|
||||||
@ -117,8 +117,10 @@ model User {
|
|||||||
SubAct SubAct[]
|
SubAct SubAct[]
|
||||||
MuteSub MuteSub[]
|
MuteSub MuteSub[]
|
||||||
Wallet Wallet[]
|
Wallet Wallet[]
|
||||||
TerritoryTransfers TerritoryTransfer[] @relation("TerritoryTransfer_oldUser")
|
TerritoryTransfers TerritoryTransfer[] @relation("TerritoryTransfer_oldUser")
|
||||||
TerritoryReceives TerritoryTransfer[] @relation("TerritoryTransfer_newUser")
|
TerritoryReceives TerritoryTransfer[] @relation("TerritoryTransfer_newUser")
|
||||||
|
AncestorReplies Reply[] @relation("AncestorReplyUser")
|
||||||
|
Replies Reply[]
|
||||||
|
|
||||||
@@index([photoId])
|
@@index([photoId])
|
||||||
@@index([createdAt], map: "users.created_at_index")
|
@@index([createdAt], map: "users.created_at_index")
|
||||||
@ -387,6 +389,8 @@ model Item {
|
|||||||
uploadId Int?
|
uploadId Int?
|
||||||
outlawed Boolean @default(false)
|
outlawed Boolean @default(false)
|
||||||
pollExpiresAt DateTime?
|
pollExpiresAt DateTime?
|
||||||
|
Ancestors Reply[] @relation("AncestorReplyItem")
|
||||||
|
Replies Reply[]
|
||||||
|
|
||||||
@@index([uploadId])
|
@@index([uploadId])
|
||||||
@@index([bio], map: "Item.bio_index")
|
@@index([bio], map: "Item.bio_index")
|
||||||
@ -406,6 +410,28 @@ model Item {
|
|||||||
@@index([weightedVotes], map: "Item.weightedVotes_index")
|
@@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
|
// TODO: make all Item's forward 100% of sats to the OP by default
|
||||||
// so that forwards aren't a special case everywhere
|
// so that forwards aren't a special case everywhere
|
||||||
model ItemForward {
|
model ItemForward {
|
||||||
@ -488,13 +514,13 @@ model Sub {
|
|||||||
moderatedCount Int @default(0)
|
moderatedCount Int @default(0)
|
||||||
nsfw Boolean @default(false)
|
nsfw Boolean @default(false)
|
||||||
|
|
||||||
parent Sub? @relation("ParentChildren", fields: [parentName], references: [name])
|
parent Sub? @relation("ParentChildren", fields: [parentName], references: [name])
|
||||||
children Sub[] @relation("ParentChildren")
|
children Sub[] @relation("ParentChildren")
|
||||||
user User @relation(fields: [userId], references: [id], onDelete: Cascade)
|
user User @relation(fields: [userId], references: [id], onDelete: Cascade)
|
||||||
Item Item[]
|
Item Item[]
|
||||||
SubAct SubAct[]
|
SubAct SubAct[]
|
||||||
MuteSub MuteSub[]
|
MuteSub MuteSub[]
|
||||||
SubSubscription SubSubscription[]
|
SubSubscription SubSubscription[]
|
||||||
TerritoryTransfer TerritoryTransfer[]
|
TerritoryTransfer TerritoryTransfer[]
|
||||||
|
|
||||||
@@index([parentName])
|
@@index([parentName])
|
||||||
@ -779,14 +805,14 @@ model Log {
|
|||||||
}
|
}
|
||||||
|
|
||||||
model TerritoryTransfer {
|
model TerritoryTransfer {
|
||||||
id Int @id @default(autoincrement())
|
id Int @id @default(autoincrement())
|
||||||
createdAt DateTime @default(now()) @map("created_at")
|
createdAt DateTime @default(now()) @map("created_at")
|
||||||
oldUserId Int
|
oldUserId Int
|
||||||
newUserId Int
|
newUserId Int
|
||||||
subName String @db.Citext
|
subName String @db.Citext
|
||||||
oldUser User @relation("TerritoryTransfer_oldUser", fields: [oldUserId], references: [id], onDelete: Cascade)
|
oldUser User @relation("TerritoryTransfer_oldUser", fields: [oldUserId], references: [id], onDelete: Cascade)
|
||||||
newUser User @relation("TerritoryTransfer_newUser", fields: [newUserId], references: [id], onDelete: Cascade)
|
newUser User @relation("TerritoryTransfer_newUser", fields: [newUserId], references: [id], onDelete: Cascade)
|
||||||
sub Sub @relation(fields: [subName], references: [name], onDelete: Cascade)
|
sub Sub @relation(fields: [subName], references: [name], onDelete: Cascade)
|
||||||
|
|
||||||
@@index([createdAt, newUserId], map: "TerritoryTransfer.newUserId_index")
|
@@index([createdAt, newUserId], map: "TerritoryTransfer.newUserId_index")
|
||||||
@@index([createdAt, oldUserId], map: "TerritoryTransfer.oldUserId_index")
|
@@index([createdAt, oldUserId], map: "TerritoryTransfer.oldUserId_index")
|
||||||
|
Loading…
x
Reference in New Issue
Block a user