From 851f37de6ff5b98397982d75a5c55d59c86cf134 Mon Sep 17 00:00:00 2001 From: Eliezer Steinbock <3090527+elie222@users.noreply.github.com> Date: Tue, 6 Jan 2026 01:49:53 +0200 Subject: [PATCH 1/2] fix(reply-zero): use raw SQL for correct distinct pagination MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit Prisma's `distinct` clause applies AFTER skip/take, causing incorrect pagination. Switch to PostgreSQL DISTINCT ON to apply distinct filtering BEFORE pagination, ensuring consistent page sizes and accurate totals. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 --- .../reply-zero/fetch-trackers.ts | 54 +++++++++---------- 1 file changed, 24 insertions(+), 30 deletions(-) diff --git a/apps/web/app/(app)/[emailAccountId]/reply-zero/fetch-trackers.ts b/apps/web/app/(app)/[emailAccountId]/reply-zero/fetch-trackers.ts index f9eb9c2e8..ed6ba3d12 100644 --- a/apps/web/app/(app)/[emailAccountId]/reply-zero/fetch-trackers.ts +++ b/apps/web/app/(app)/[emailAccountId]/reply-zero/fetch-trackers.ts @@ -1,4 +1,5 @@ import prisma from "@/utils/prisma"; +import { Prisma, type ThreadTracker } from "@/generated/prisma/client"; import type { ThreadTrackerType } from "@/generated/prisma/enums"; import { getDateFilter, type TimeRange } from "./date-filter"; @@ -18,37 +19,30 @@ export async function getPaginatedThreadTrackers({ const skip = (page - 1) * PAGE_SIZE; const dateFilter = getDateFilter(timeRange); + const dateClause = dateFilter + ? Prisma.sql`AND "sentAt" <= ${dateFilter.lte}` + : Prisma.empty; + const [trackers, total] = await Promise.all([ - prisma.threadTracker.findMany({ - where: { - emailAccountId, - resolved: false, - type, - sentAt: dateFilter, - }, - orderBy: { - createdAt: "desc", - }, - distinct: ["threadId"], - take: PAGE_SIZE, - skip, - }), - dateFilter - ? prisma.$queryRaw<[{ count: bigint }]>` - SELECT COUNT(DISTINCT "threadId") as count - FROM "ThreadTracker" - WHERE "emailAccountId" = ${emailAccountId} - AND "resolved" = false - AND "type" = ${type}::text::"ThreadTrackerType" - AND "sentAt" <= ${dateFilter.lte} - ` - : prisma.$queryRaw<[{ count: bigint }]>` - SELECT COUNT(DISTINCT "threadId") as count - FROM "ThreadTracker" - WHERE "emailAccountId" = ${emailAccountId} - AND "resolved" = false - AND "type" = ${type}::text::"ThreadTrackerType" - `, + prisma.$queryRaw` + SELECT DISTINCT ON ("threadId") * + FROM "ThreadTracker" + WHERE "emailAccountId" = ${emailAccountId} + AND "resolved" = false + AND "type" = ${type}::text::"ThreadTrackerType" + ${dateClause} + ORDER BY "threadId", "createdAt" DESC + LIMIT ${PAGE_SIZE} + OFFSET ${skip} + `, + prisma.$queryRaw<[{ count: bigint }]>` + SELECT COUNT(DISTINCT "threadId") as count + FROM "ThreadTracker" + WHERE "emailAccountId" = ${emailAccountId} + AND "resolved" = false + AND "type" = ${type}::text::"ThreadTrackerType" + ${dateClause} + `, ]); const count = Number(total?.[0]?.count); From 140a1bc375ea0c532fc7d02d5fcf44f2ba7970ec Mon Sep 17 00:00:00 2001 From: Eliezer Steinbock <3090527+elie222@users.noreply.github.com> Date: Tue, 6 Jan 2026 02:11:38 +0200 Subject: [PATCH 2/2] fix: wrap DISTINCT ON in subquery to restore createdAt ordering MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit PostgreSQL's DISTINCT ON requires ORDER BY to start with the DISTINCT column, so the outer query must re-order by createdAt DESC for proper pagination ordering (most recent threads first). 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 --- .../reply-zero/fetch-trackers.ts | 17 ++++++++++------- 1 file changed, 10 insertions(+), 7 deletions(-) diff --git a/apps/web/app/(app)/[emailAccountId]/reply-zero/fetch-trackers.ts b/apps/web/app/(app)/[emailAccountId]/reply-zero/fetch-trackers.ts index ed6ba3d12..da8a0bb16 100644 --- a/apps/web/app/(app)/[emailAccountId]/reply-zero/fetch-trackers.ts +++ b/apps/web/app/(app)/[emailAccountId]/reply-zero/fetch-trackers.ts @@ -25,13 +25,16 @@ export async function getPaginatedThreadTrackers({ const [trackers, total] = await Promise.all([ prisma.$queryRaw` - SELECT DISTINCT ON ("threadId") * - FROM "ThreadTracker" - WHERE "emailAccountId" = ${emailAccountId} - AND "resolved" = false - AND "type" = ${type}::text::"ThreadTrackerType" - ${dateClause} - ORDER BY "threadId", "createdAt" DESC + SELECT * FROM ( + SELECT DISTINCT ON ("threadId") * + FROM "ThreadTracker" + WHERE "emailAccountId" = ${emailAccountId} + AND "resolved" = false + AND "type" = ${type}::text::"ThreadTrackerType" + ${dateClause} + ORDER BY "threadId", "createdAt" DESC + ) AS distinct_threads + ORDER BY "createdAt" DESC LIMIT ${PAGE_SIZE} OFFSET ${skip} `,