From 01b021a33719edc803bd8ebc3d869780a3316a47 Mon Sep 17 00:00:00 2001 From: Keyan <34140557+huumn@users.noreply.github.com> Date: Wed, 29 Jan 2025 19:00:05 -0600 Subject: [PATCH] comment pagination with limit/offset (#1824) * basic query with limit/offset * roughly working increment * working limiting/pageable queries * denormalize direct comments + full comments below threshold * notifications in megathread + working nest view more buttons * fix empty comment footer * make comments nested resolver again * use time in cursor to avoid duplicates * squash migrations * do not need item.comments undefined checks --- api/paidAction/itemCreate.js | 4 +- api/resolvers/item.js | 100 +++++++++--- api/typeDefs/item.js | 3 +- components/comment.js | 26 +++- components/comments.js | 17 +- components/item-full.js | 8 +- components/reply.js | 11 +- fragments/comments.js | 14 +- fragments/items.js | 11 +- fragments/paidAction.js | 4 +- fragments/users.js | 13 +- lib/apollo.js | 21 ++- lib/constants.js | 5 +- lib/cursor.js | 1 + lib/item.js | 6 +- pages/items/[id]/index.js | 8 +- .../migration.sql | 147 ++++++++++++++++++ prisma/schema.prisma | 1 + 18 files changed, 338 insertions(+), 62 deletions(-) create mode 100644 prisma/migrations/20250118010433_comment_pages/migration.sql diff --git a/api/paidAction/itemCreate.js b/api/paidAction/itemCreate.js index 086f4b70..8d284657 100644 --- a/api/paidAction/itemCreate.js +++ b/api/paidAction/itemCreate.js @@ -235,7 +235,9 @@ export async function onPaid ({ invoice, id }, context) { SET ncomments = "Item".ncomments + 1, "lastCommentAt" = GREATEST("Item"."lastCommentAt", comment.created_at), "weightedComments" = "Item"."weightedComments" + - CASE WHEN comment."userId" = "Item"."userId" THEN 0 ELSE comment.trust END + CASE WHEN comment."userId" = "Item"."userId" THEN 0 ELSE comment.trust END, + "nDirectComments" = "Item"."nDirectComments" + + CASE WHEN comment."parentId" = "Item".id THEN 1 ELSE 0 END FROM comment WHERE "Item".path @> comment.path AND "Item".id <> comment.id RETURNING "Item".* diff --git a/api/resolvers/item.js b/api/resolvers/item.js index ac169d11..fae63dc2 100644 --- a/api/resolvers/item.js +++ b/api/resolvers/item.js @@ -9,7 +9,10 @@ import { USER_ID, POLL_COST, ADMIN_ITEMS, GLOBAL_SEED, NOFOLLOW_LIMIT, UNKNOWN_LINK_REL, SN_ADMIN_IDS, BOOST_MULT, - ITEM_EDIT_SECONDS + ITEM_EDIT_SECONDS, + COMMENTS_LIMIT, + COMMENTS_OF_COMMENT_LIMIT, + FULL_COMMENTS_THRESHOLD } from '@/lib/constants' import { msatsToSats } from '@/lib/format' import { parse } from 'tldts' @@ -25,39 +28,76 @@ import { GqlAuthenticationError, GqlInputError } from '@/lib/error' import { verifyHmac } from './wallet' function commentsOrderByClause (me, models, sort) { + const sharedSortsArray = [] + sharedSortsArray.push('("Item"."pinId" IS NOT NULL) DESC') + sharedSortsArray.push('("Item"."deletedAt" IS NULL) DESC') + const sharedSorts = sharedSortsArray.join(', ') + if (sort === 'recent') { - return 'ORDER BY ("Item"."deletedAt" IS NULL) DESC, ("Item".cost > 0 OR "Item"."weightedVotes" - "Item"."weightedDownVotes" > 0) DESC, COALESCE("Item"."invoicePaidAt", "Item".created_at) DESC, "Item".id DESC' + return `ORDER BY ${sharedSorts}, + ("Item".cost > 0 OR "Item"."weightedVotes" - "Item"."weightedDownVotes" > 0) DESC, + COALESCE("Item"."invoicePaidAt", "Item".created_at) DESC, "Item".id DESC` } if (me && sort === 'hot') { - return `ORDER BY ("Item"."deletedAt" IS NULL) DESC, COALESCE( - personal_hot_score, - ${orderByNumerator({ models, commentScaler: 0, considerBoost: true })}/POWER(GREATEST(3, EXTRACT(EPOCH FROM (now_utc() - "Item".created_at))/3600), 1.3)) DESC NULLS LAST, - "Item".msats DESC, ("Item".cost > 0) DESC, "Item".id DESC` + return `ORDER BY ${sharedSorts}, + "personal_hot_score" DESC NULLS LAST, + "Item".msats DESC, ("Item".cost > 0) DESC, "Item".id DESC` } else { if (sort === 'top') { - return `ORDER BY ("Item"."deletedAt" IS NULL) DESC, ${orderByNumerator({ models, commentScaler: 0 })} DESC NULLS LAST, "Item".msats DESC, ("Item".cost > 0) DESC, "Item".id DESC` + return `ORDER BY ${sharedSorts}, ${orderByNumerator({ models, commentScaler: 0 })} DESC NULLS LAST, "Item".msats DESC, ("Item".cost > 0) DESC, "Item".id DESC` } else { - return `ORDER BY ("Item"."deletedAt" IS NULL) DESC, ${orderByNumerator({ models, commentScaler: 0, considerBoost: true })}/POWER(GREATEST(3, EXTRACT(EPOCH FROM (now_utc() - "Item".created_at))/3600), 1.3) DESC NULLS LAST, "Item".msats DESC, ("Item".cost > 0) DESC, "Item".id DESC` + return `ORDER BY ${sharedSorts}, ${orderByNumerator({ models, commentScaler: 0, considerBoost: true })}/POWER(GREATEST(3, EXTRACT(EPOCH FROM (now_utc() - "Item".created_at))/3600), 1.3) DESC NULLS LAST, "Item".msats DESC, ("Item".cost > 0) DESC, "Item".id DESC` } } } -async function comments (me, models, id, sort) { +async function comments (me, models, item, sort, cursor) { const orderBy = commentsOrderByClause(me, models, sort) - if (me) { - const filter = ` AND ("Item"."invoiceActionState" IS NULL OR "Item"."invoiceActionState" = 'PAID' OR "Item"."userId" = ${me.id}) ` - const [{ item_comments_zaprank_with_me: comments }] = await models.$queryRawUnsafe( - 'SELECT item_comments_zaprank_with_me($1::INTEGER, $2::INTEGER, $3::INTEGER, $4::INTEGER, $5, $6)', - Number(id), GLOBAL_SEED, Number(me.id), COMMENT_DEPTH_LIMIT, filter, orderBy) - return comments + if (item.nDirectComments === 0) { + return { + comments: [], + cursor: null + } } - const filter = ' AND ("Item"."invoiceActionState" IS NULL OR "Item"."invoiceActionState" = \'PAID\') ' - const [{ item_comments: comments }] = await models.$queryRawUnsafe( - 'SELECT item_comments($1::INTEGER, $2::INTEGER, $3, $4)', Number(id), COMMENT_DEPTH_LIMIT, filter, orderBy) - return comments + const decodedCursor = decodeCursor(cursor) + const offset = decodedCursor.offset + + // XXX what a mess + let comments + if (me) { + const filter = ` AND ("Item"."invoiceActionState" IS NULL OR "Item"."invoiceActionState" = 'PAID' OR "Item"."userId" = ${me.id}) AND "Item".created_at <= '${decodedCursor.time.toISOString()}'::TIMESTAMP(3) ` + if (item.ncomments > FULL_COMMENTS_THRESHOLD) { + const [{ item_comments_zaprank_with_me_limited: limitedComments }] = await models.$queryRawUnsafe( + 'SELECT item_comments_zaprank_with_me_limited($1::INTEGER, $2::INTEGER, $3::INTEGER, $4::INTEGER, $5::INTEGER, $6::INTEGER, $7::INTEGER, $8, $9)', + Number(item.id), GLOBAL_SEED, Number(me.id), COMMENTS_LIMIT, offset, COMMENTS_OF_COMMENT_LIMIT, COMMENT_DEPTH_LIMIT, filter, orderBy) + comments = limitedComments + } else { + const [{ item_comments_zaprank_with_me: fullComments }] = await models.$queryRawUnsafe( + 'SELECT item_comments_zaprank_with_me($1::INTEGER, $2::INTEGER, $3::INTEGER, $4::INTEGER, $5, $6)', + Number(item.id), GLOBAL_SEED, Number(me.id), COMMENT_DEPTH_LIMIT, filter, orderBy) + comments = fullComments + } + } else { + const filter = ` AND ("Item"."invoiceActionState" IS NULL OR "Item"."invoiceActionState" = 'PAID') AND "Item".created_at <= '${decodedCursor.time.toISOString()}'::TIMESTAMP(3) ` + if (item.ncomments > FULL_COMMENTS_THRESHOLD) { + const [{ item_comments_limited: limitedComments }] = await models.$queryRawUnsafe( + 'SELECT item_comments_limited($1::INTEGER, $2::INTEGER, $3::INTEGER, $4::INTEGER, $5::INTEGER, $6, $7)', + Number(item.id), COMMENTS_LIMIT, offset, COMMENTS_OF_COMMENT_LIMIT, COMMENT_DEPTH_LIMIT, filter, orderBy) + comments = limitedComments + } else { + const [{ item_comments: fullComments }] = await models.$queryRawUnsafe( + 'SELECT item_comments($1::INTEGER, $2::INTEGER, $3, $4)', Number(item.id), COMMENT_DEPTH_LIMIT, filter, orderBy) + comments = fullComments + } + } + + return { + comments, + cursor: comments.length + offset < item.nDirectComments ? nextCursorEncoded(decodedCursor, COMMENTS_LIMIT) : null + } } export async function getItem (parent, { id }, { me, models }) { @@ -1173,11 +1213,25 @@ export default { } }) }, - comments: async (item, { sort }, { me, models }) => { - if (typeof item.comments !== 'undefined') return item.comments - if (item.ncomments === 0) return [] + comments: async (item, { sort, cursor }, { me, models }) => { + if (typeof item.comments !== 'undefined') { + if (Array.isArray(item.comments)) { + return { + comments: item.comments, + cursor: null + } + } + return item.comments + } - return comments(me, models, item.id, sort || defaultCommentSort(item.pinId, item.bioId, item.createdAt)) + if (item.ncomments === 0) { + return { + comments: [], + cursor: null + } + } + + return comments(me, models, item, sort || defaultCommentSort(item.pinId, item.bioId, item.createdAt), cursor) }, freedFreebie: async (item) => { return item.weightedVotes - item.weightedDownVotes > 0 diff --git a/api/typeDefs/item.js b/api/typeDefs/item.js index f817e340..d75ade1d 100644 --- a/api/typeDefs/item.js +++ b/api/typeDefs/item.js @@ -145,7 +145,8 @@ export default gql` bio: Boolean! paidImgLink: Boolean ncomments: Int! - comments(sort: String): [Item!]! + nDirectComments: Int! + comments(sort: String, cursor: String): Comments! path: String position: Int prior: Int diff --git a/components/comment.js b/components/comment.js index 9322b9de..74d0247b 100644 --- a/components/comment.js +++ b/components/comment.js @@ -254,11 +254,17 @@ export default function Comment ({ } {children}
- {item.comments && !noComments - ? item.comments.map((item) => ( - - )) + {item.comments.comments && !noComments + ? ( + <> + {item.comments.comments.map((item) => ( + + ))} + {item.comments.comments.length < item.nDirectComments && } + + ) : null} + {/* TODO: add link to more comments if they're limited */}
) @@ -267,6 +273,18 @@ export default function Comment ({ ) } +export function ViewAllReplies ({ id, nshown, nhas }) { + const text = `view all ${nhas} replies` + + return ( +
+ + {text} + +
+ ) +} + export function CommentSkeleton ({ skeletonChildren }) { return (
diff --git a/components/comments.js b/components/comments.js index c475dc25..cb5d8641 100644 --- a/components/comments.js +++ b/components/comments.js @@ -1,4 +1,4 @@ -import { Fragment } from 'react' +import { Fragment, useMemo } from 'react' import Comment, { CommentSkeleton } from './comment' import styles from './header.module.css' import Nav from 'react-bootstrap/Nav' @@ -6,6 +6,8 @@ import Navbar from 'react-bootstrap/Navbar' import { numWithUnits } from '@/lib/format' import { defaultCommentSort } from '@/lib/item' import { useRouter } from 'next/router' +import MoreFooter from './more-footer' +import { FULL_COMMENTS_THRESHOLD } from '@/lib/constants' export function CommentsHeader ({ handleSort, pinned, bio, parentCreatedAt, commentSats }) { const router = useRouter() @@ -60,10 +62,13 @@ export function CommentsHeader ({ handleSort, pinned, bio, parentCreatedAt, comm ) } -export default function Comments ({ parentId, pinned, bio, parentCreatedAt, commentSats, comments, ...props }) { +export default function Comments ({ + parentId, pinned, bio, parentCreatedAt, + commentSats, comments, commentsCursor, fetchMoreComments, ncomments, ...props +}) { const router = useRouter() - const pins = comments?.filter(({ position }) => !!position).sort((a, b) => a.position - b.position) + const pins = useMemo(() => comments?.filter(({ position }) => !!position).sort((a, b) => a.position - b.position), [comments]) return ( <> @@ -91,6 +96,12 @@ export default function Comments ({ parentId, pinned, bio, parentCreatedAt, comm {comments.filter(({ position }) => !position).map(item => ( ))} + {ncomments > FULL_COMMENTS_THRESHOLD && + } ) } diff --git a/components/item-full.js b/components/item-full.js index 5a148ea3..72c60b9c 100644 --- a/components/item-full.js +++ b/components/item-full.js @@ -160,7 +160,7 @@ function ItemText ({ item }) { : {item.text} } -export default function ItemFull ({ item, bio, rank, ...props }) { +export default function ItemFull ({ item, fetchMoreComments, bio, rank, ...props }) { useEffect(() => { commentsViewed(item) }, [item.lastCommentAt]) @@ -186,7 +186,11 @@ export default function ItemFull ({ item, bio, rank, ...props }) {
} diff --git a/components/reply.js b/components/reply.js index 752c7316..e901298c 100644 --- a/components/reply.js +++ b/components/reply.js @@ -55,9 +55,9 @@ export default forwardRef(function Reply ({ const placeholder = useMemo(() => { return [ - 'comment for currency?', + 'comment for currency', 'fractions of a penny for your thoughts?', - 'put your money where your mouth is?' + 'put your money where your mouth is' ][parentId % 3] }, [parentId]) @@ -70,13 +70,16 @@ export default forwardRef(function Reply ({ cache.modify({ id: `Item:${parentId}`, fields: { - comments (existingCommentRefs = []) { + comments (existingComments = {}) { const newCommentRef = cache.writeFragment({ data: result, fragment: COMMENTS, fragmentName: 'CommentsRecursive' }) - return [newCommentRef, ...existingCommentRefs] + return { + cursor: existingComments.cursor, + comments: [newCommentRef, ...(existingComments?.comments || [])] + } } }, optimistic: true diff --git a/fragments/comments.js b/fragments/comments.js index 991bc299..04b2a71a 100644 --- a/fragments/comments.js +++ b/fragments/comments.js @@ -46,6 +46,7 @@ export const COMMENT_FIELDS = gql` mine otsHash ncomments + nDirectComments imgproxyUrls rel apiKey @@ -66,6 +67,7 @@ export const COMMENTS_ITEM_EXT_FIELDS = gql` id title bounty + ncomments bountyPaidTo subName sub { @@ -89,19 +91,23 @@ export const COMMENTS = gql` fragment CommentsRecursive on Item { ...CommentFields comments { - ...CommentFields comments { ...CommentFields comments { - ...CommentFields comments { ...CommentFields comments { - ...CommentFields comments { ...CommentFields comments { - ...CommentFields + comments { + ...CommentFields + comments { + comments { + ...CommentFields + } + } + } } } } diff --git a/fragments/items.js b/fragments/items.js index f51d1771..c7e1e57a 100644 --- a/fragments/items.js +++ b/fragments/items.js @@ -57,6 +57,7 @@ export const ITEM_FIELDS = gql` freebie bio ncomments + nDirectComments commentSats commentCredits lastCommentAt @@ -94,6 +95,7 @@ export const ITEM_FULL_FIELDS = gql` bountyPaidTo subName mine + ncomments user { id name @@ -166,13 +168,16 @@ export const ITEM_FULL = gql` ${ITEM_FULL_FIELDS} ${POLL_FIELDS} ${COMMENTS} - query Item($id: ID!, $sort: String) { + query Item($id: ID!, $sort: String, $cursor: String) { item(id: $id) { ...ItemFullFields prior ...PollFields - comments(sort: $sort) { - ...CommentsRecursive + comments(sort: $sort, cursor: $cursor) { + cursor + comments { + ...CommentsRecursive + } } } }` diff --git a/fragments/paidAction.js b/fragments/paidAction.js index 0aa0a71a..7a4bd44c 100644 --- a/fragments/paidAction.js +++ b/fragments/paidAction.js @@ -25,7 +25,9 @@ const ITEM_PAID_ACTION_FIELDS = gql` reminderScheduledAt ...CommentFields comments { - ...CommentsRecursive + comments { + ...CommentsRecursive + } } } }` diff --git a/fragments/users.js b/fragments/users.js index c65cc2a0..94e1a7a6 100644 --- a/fragments/users.js +++ b/fragments/users.js @@ -297,17 +297,20 @@ export const USER_FULL = gql` ${USER_FIELDS} ${ITEM_FULL_FIELDS} ${COMMENTS} - query User($name: String!, $sort: String) { + query User($name: String!, $sort: String, $cursor: String) { user(name: $name) { ...UserFields bio { ...ItemFullFields - comments(sort: $sort) { - ...CommentsRecursive + comments(sort: $sort, cursor: $cursor) { + cursor + comments { + ...CommentsRecursive + } } } - } -}` + } + }` export const USER = gql` ${USER_FIELDS} diff --git a/lib/apollo.js b/lib/apollo.js index 6e2eeab1..c3b7a6f5 100644 --- a/lib/apollo.js +++ b/lib/apollo.js @@ -1,7 +1,7 @@ import { ApolloClient, InMemoryCache, HttpLink, makeVar, split } from '@apollo/client' import { BatchHttpLink } from '@apollo/client/link/batch-http' import { decodeCursor, LIMIT } from './cursor' -import { SSR } from './constants' +import { COMMENTS_LIMIT, SSR } from './constants' function isFirstPage (cursor, existingThings, limit = LIMIT) { if (cursor) { @@ -201,12 +201,6 @@ function getClient (uri) { } } }, - comments: { - keyArgs: ['id', 'sort'], - merge (existing, incoming) { - return incoming - } - }, related: { keyArgs: ['id', 'title', 'minMatch', 'limit'], merge (existing, incoming, { args }) { @@ -277,6 +271,19 @@ function getClient (uri) { }, Item: { fields: { + comments: { + keyArgs: ['sort'], + merge (existing, incoming) { + if (isFirstPage(incoming.cursor, existing?.comments, COMMENTS_LIMIT)) { + return incoming + } + + return { + cursor: incoming.cursor, + comments: [...(existing?.comments || []), ...incoming.comments] + } + } + }, meAnonSats: { read (existingAmount, { readField }) { if (SSR) return null diff --git a/lib/constants.js b/lib/constants.js index 3372d994..a2e2f28f 100644 --- a/lib/constants.js +++ b/lib/constants.js @@ -40,7 +40,10 @@ export const BOUNTY_MAX = 10000000 export const POST_TYPES = ['LINK', 'DISCUSSION', 'BOUNTY', 'POLL'] export const TERRITORY_BILLING_TYPES = ['MONTHLY', 'YEARLY', 'ONCE'] export const TERRITORY_GRACE_DAYS = 5 -export const COMMENT_DEPTH_LIMIT = 8 +export const COMMENT_DEPTH_LIMIT = 6 +export const COMMENTS_LIMIT = 50 +export const FULL_COMMENTS_THRESHOLD = 200 +export const COMMENTS_OF_COMMENT_LIMIT = 2 export const MAX_TITLE_LENGTH = 80 export const MIN_TITLE_LENGTH = 5 export const MAX_POST_TEXT_LENGTH = 100000 // 100k diff --git a/lib/cursor.js b/lib/cursor.js index 476abc69..6f245b4f 100644 --- a/lib/cursor.js +++ b/lib/cursor.js @@ -5,6 +5,7 @@ export function decodeCursor (cursor) { return { offset: 0, time: new Date() } } else { const res = JSON.parse(Buffer.from(cursor, 'base64')) + res.offset = Number(res.offset) res.time = new Date(res.time) return res } diff --git a/lib/item.js b/lib/item.js index 33b0111e..cecdb1a1 100644 --- a/lib/item.js +++ b/lib/item.js @@ -1,4 +1,4 @@ -import { COMMENT_DEPTH_LIMIT, OLD_ITEM_DAYS } from './constants' +import { COMMENT_DEPTH_LIMIT, FULL_COMMENTS_THRESHOLD, OLD_ITEM_DAYS } from './constants' import { datePivot } from './time' export const defaultCommentSort = (pinned, bio, createdAt) => { @@ -106,6 +106,10 @@ export const deleteReminders = async ({ id, userId, models }) => { } export const commentSubTreeRootId = (item) => { + if (item.root?.ncomments > FULL_COMMENTS_THRESHOLD) { + return item.id + } + const path = item.path.split('.') return path.slice(-(COMMENT_DEPTH_LIMIT - 1))[0] } diff --git a/pages/items/[id]/index.js b/pages/items/[id]/index.js index da00f573..1d0c2c83 100644 --- a/pages/items/[id]/index.js +++ b/pages/items/[id]/index.js @@ -14,15 +14,19 @@ export const getServerSideProps = getGetServerSideProps({ export default function Item ({ ssrData }) { const router = useRouter() - const { data } = useQuery(ITEM_FULL, { variables: { ...router.query } }) + const { data, fetchMore } = useQuery(ITEM_FULL, { variables: { ...router.query } }) if (!data && !ssrData) return const { item } = data || ssrData const sub = item.subName || item.root?.subName + const fetchMoreComments = async () => { + await fetchMore({ variables: { ...router.query, cursor: item.comments.cursor } }) + } + return ( - + ) } diff --git a/prisma/migrations/20250118010433_comment_pages/migration.sql b/prisma/migrations/20250118010433_comment_pages/migration.sql new file mode 100644 index 00000000..d5f52b43 --- /dev/null +++ b/prisma/migrations/20250118010433_comment_pages/migration.sql @@ -0,0 +1,147 @@ +-- AlterTable +ALTER TABLE "Item" ADD COLUMN "nDirectComments" INTEGER NOT NULL DEFAULT 0; + +-- Update nDirectComments +UPDATE "Item" +SET "nDirectComments" = "DirectComments"."nDirectComments" +FROM ( + SELECT "Item"."parentId" AS "id", COUNT(*) AS "nDirectComments" + FROM "Item" + WHERE "Item"."parentId" IS NOT NULL + GROUP BY "Item"."parentId" +) AS "DirectComments" +WHERE "Item"."id" = "DirectComments"."id"; + +-- add limit and offset +CREATE OR REPLACE FUNCTION item_comments_zaprank_with_me_limited( + _item_id int, _global_seed int, _me_id int, _limit int, _offset int, _grandchild_limit int, + _level int, _where text, _order_by text) + RETURNS jsonb + LANGUAGE plpgsql VOLATILE PARALLEL SAFE AS +$$ +DECLARE + result jsonb; +BEGIN + IF _level < 1 THEN + RETURN '[]'::jsonb; + END IF; + + EXECUTE 'CREATE TEMP TABLE IF NOT EXISTS t_item ON COMMIT DROP AS ' + || 'WITH RECURSIVE base AS ( ' + || ' (SELECT "Item".*, 1 as level, ROW_NUMBER() OVER () as rn, ' + || ' GREATEST(g.tf_hot_score, l.tf_hot_score) AS personal_hot_score, ' + || ' GREATEST(g.tf_top_score, l.tf_top_score) AS personal_top_score ' + || ' FROM "Item" ' + || ' LEFT JOIN zap_rank_personal_view g ON g."viewerId" = $2 AND g.id = "Item".id ' + || ' LEFT JOIN zap_rank_personal_view l ON l."viewerId" = $3 AND l.id = g.id ' + || ' WHERE "Item"."parentId" = $1 ' + || _order_by || ' ' + || ' LIMIT $4 ' + || ' OFFSET $5) ' + || ' UNION ALL ' + || ' (SELECT "Item".*, b.level + 1, ROW_NUMBER() OVER (PARTITION BY "Item"."parentId" ' || _order_by || ') as rn, ' + || ' GREATEST(g.tf_hot_score, l.tf_hot_score) AS personal_hot_score, ' + || ' GREATEST(g.tf_top_score, l.tf_top_score) AS personal_top_score ' + || ' FROM "Item" ' + || ' JOIN base b ON "Item"."parentId" = b.id ' + || ' LEFT JOIN zap_rank_personal_view g ON g."viewerId" = $2 AND g.id = "Item".id ' + || ' LEFT JOIN zap_rank_personal_view l ON l."viewerId" = $3 AND l.id = g.id ' + || ' WHERE b.level < $7 AND (b.level = 1 OR b.rn <= $6)) ' + || ') ' + || 'SELECT "Item".*, ' + || ' "Item".created_at at time zone ''UTC'' AS "createdAt", ' + || ' "Item".updated_at at time zone ''UTC'' AS "updatedAt", ' + || ' "Item"."invoicePaidAt" at time zone ''UTC'' AS "invoicePaidAtUTC", ' + || ' to_jsonb(users.*) || jsonb_build_object(''meMute'', "Mute"."mutedId" IS NOT NULL) AS user, ' + || ' COALESCE("ItemAct"."meMsats", 0) AS "meMsats", ' + || ' COALESCE("ItemAct"."mePendingMsats", 0) as "mePendingMsats", ' + || ' COALESCE("ItemAct"."meDontLikeMsats", 0) AS "meDontLikeMsats", ' + || ' COALESCE("ItemAct"."meMcredits", 0) AS "meMcredits", ' + || ' COALESCE("ItemAct"."mePendingMcredits", 0) as "mePendingMcredits", ' + || ' "Bookmark"."itemId" IS NOT NULL AS "meBookmark", ' + || ' "ThreadSubscription"."itemId" IS NOT NULL AS "meSubscription" ' + || 'FROM base "Item" ' + || 'JOIN users ON users.id = "Item"."userId" ' + || ' LEFT JOIN "Mute" ON "Mute"."muterId" = $3 AND "Mute"."mutedId" = "Item"."userId" ' + || ' LEFT JOIN "Bookmark" ON "Bookmark"."userId" = $3 AND "Bookmark"."itemId" = "Item".id ' + || ' LEFT JOIN "ThreadSubscription" ON "ThreadSubscription"."userId" = $3 AND "ThreadSubscription"."itemId" = "Item".id ' + || 'LEFT JOIN LATERAL ( ' + || ' SELECT "itemId", ' + || ' sum("ItemAct".msats) FILTER (WHERE "invoiceActionState" IS DISTINCT FROM ''FAILED'' AND "InvoiceForward".id IS NOT NULL AND (act = ''FEE'' OR act = ''TIP'')) AS "meMsats", ' + || ' sum("ItemAct".msats) FILTER (WHERE "invoiceActionState" IS DISTINCT FROM ''FAILED'' AND "InvoiceForward".id IS NULL AND (act = ''FEE'' OR act = ''TIP'')) AS "meMcredits", ' + || ' sum("ItemAct".msats) FILTER (WHERE "invoiceActionState" IS NOT DISTINCT FROM ''PENDING'' AND "InvoiceForward".id IS NOT NULL AND (act = ''FEE'' OR act = ''TIP'')) AS "mePendingMsats", ' + || ' sum("ItemAct".msats) FILTER (WHERE "invoiceActionState" IS NOT DISTINCT FROM ''PENDING'' AND "InvoiceForward".id IS NULL AND (act = ''FEE'' OR act = ''TIP'')) AS "mePendingMcredits", ' + || ' sum("ItemAct".msats) FILTER (WHERE "invoiceActionState" IS DISTINCT FROM ''FAILED'' AND act = ''DONT_LIKE_THIS'') AS "meDontLikeMsats" ' + || ' FROM "ItemAct" ' + || ' LEFT JOIN "Invoice" ON "Invoice".id = "ItemAct"."invoiceId" ' + || ' LEFT JOIN "InvoiceForward" ON "InvoiceForward"."invoiceId" = "Invoice"."id" ' + || ' WHERE "ItemAct"."userId" = $3 ' + || ' AND "ItemAct"."itemId" = "Item".id ' + || ' GROUP BY "ItemAct"."itemId" ' + || ') "ItemAct" ON true ' + || 'WHERE ("Item".level = 1 OR "Item".rn <= $6 - "Item".level + 2) ' || _where || ' ' + USING _item_id, _global_seed, _me_id, _limit, _offset, _grandchild_limit, _level, _where, _order_by; + + EXECUTE '' + || 'SELECT COALESCE(jsonb_agg(sub), ''[]''::jsonb) AS comments ' + || 'FROM ( ' + || ' SELECT "Item".*, item_comments_zaprank_with_me("Item".id, $2, $3, $4, $5, $6, $7 - 1, $8, $9) AS comments ' + || ' FROM t_item "Item" ' + || ' WHERE "Item"."parentId" = $1 ' + || _order_by + || ' ) sub' + INTO result USING _item_id, _global_seed, _me_id, _limit, _offset, _grandchild_limit, _level, _where, _order_by; + + RETURN result; +END +$$; + +-- add limit and offset +CREATE OR REPLACE FUNCTION item_comments_limited( + _item_id int, _limit int, _offset int, _grandchild_limit int, + _level int, _where text, _order_by text) + RETURNS jsonb + LANGUAGE plpgsql VOLATILE PARALLEL SAFE AS +$$ +DECLARE + result jsonb; +BEGIN + IF _level < 1 THEN + RETURN '[]'::jsonb; + END IF; + + EXECUTE 'CREATE TEMP TABLE IF NOT EXISTS t_item ON COMMIT DROP AS ' + || 'WITH RECURSIVE base AS ( ' + || ' (SELECT "Item".*, 1 as level, ROW_NUMBER() OVER () as rn ' + || ' FROM "Item" ' + || ' WHERE "Item"."parentId" = $1 ' + || _order_by || ' ' + || ' LIMIT $2 ' + || ' OFFSET $3) ' + || ' UNION ALL ' + || ' (SELECT "Item".*, b.level + 1, ROW_NUMBER() OVER (PARTITION BY "Item"."parentId" ' || _order_by || ') ' + || ' FROM "Item" ' + || ' JOIN base b ON "Item"."parentId" = b.id ' + || ' WHERE b.level < $5 AND (b.level = 1 OR b.rn <= $4)) ' + || ') ' + || 'SELECT "Item".*, "Item".created_at at time zone ''UTC'' AS "createdAt", "Item".updated_at at time zone ''UTC'' AS "updatedAt", ' + || ' "Item"."invoicePaidAt" at time zone ''UTC'' AS "invoicePaidAtUTC", ' + || ' to_jsonb(users.*) as user ' + || 'FROM base "Item" ' + || 'JOIN users ON users.id = "Item"."userId" ' + || 'WHERE ("Item".level = 1 OR "Item".rn <= $4) ' || _where + USING _item_id, _limit, _offset, _grandchild_limit, _level, _where, _order_by; + + + EXECUTE '' + || 'SELECT COALESCE(jsonb_agg(sub), ''[]''::jsonb) AS comments ' + || 'FROM ( ' + || ' SELECT "Item".*, item_comments("Item".id, $2, $3, $4, $5 - 1, $6, $7) AS comments ' + || ' FROM t_item "Item" ' + || ' WHERE "Item"."parentId" = $1 ' + || _order_by + || ' ) sub' + INTO result USING _item_id, _limit, _offset, _grandchild_limit, _level, _where, _order_by; + RETURN result; +END +$$; \ No newline at end of file diff --git a/prisma/schema.prisma b/prisma/schema.prisma index 5b227594..8d4ba7fd 100644 --- a/prisma/schema.prisma +++ b/prisma/schema.prisma @@ -528,6 +528,7 @@ model Item { lastCommentAt DateTime? lastZapAt DateTime? ncomments Int @default(0) + nDirectComments Int @default(0) msats BigInt @default(0) mcredits BigInt @default(0) cost Int @default(0)