fix(db-postgres): incorrect pagination results when querying hasMany relationships multiple times (#11096)

Fixes https://github.com/payloadcms/payload/issues/10810

This was caused by using `COUNT(*)` aggregation instead of
`COUNT(DISTINCT table.id)`. However, we want to use `COUNT(*)` because
`COUNT(DISTINCT table.id)` is slow on large tables. Now we fallback to
`COUNT(DISTINCT table.id)` only when `COUNT(*)` cannot work properly.

Example of a query that leads to incorrect `totalDocs`:
```ts
const res = await payload.find({
  collection: 'directors',
  limit: 10,
  where: {
    or: [
      {
        movies: {
          equals: movie2.id,
        },
      },
      {
        movies: {
          equals: movie1.id,
        },
      },
      {
        movies: {
          equals: movie1.id,
        },
      },
    ],
  },
})
```
This commit is contained in:
Sasha
2025-02-11 01:16:18 +02:00
committed by GitHub
parent fde526e07f
commit 98fec35368
6 changed files with 89 additions and 13 deletions

View File

@@ -1,7 +1,7 @@
import type { ChainedMethods } from '@payloadcms/drizzle/types'
import { chainMethods } from '@payloadcms/drizzle'
import { count } from 'drizzle-orm'
import { count, sql } from 'drizzle-orm'
import type { CountDistinct, SQLiteAdapter } from './types.js'
@@ -11,18 +11,27 @@ export const countDistinct: CountDistinct = async function countDistinct(
) {
const chainedMethods: ChainedMethods = []
joins.forEach(({ condition, table }) => {
// COUNT(DISTINCT id) is slow on large tables, so we only use DISTINCT if we have to
const visitedPaths = new Set([])
let useDistinct = false
joins.forEach(({ condition, queryPath, table }) => {
if (!useDistinct && queryPath) {
if (visitedPaths.has(queryPath)) {
useDistinct = true
} else {
visitedPaths.add(queryPath)
}
}
chainedMethods.push({
args: [table, condition],
method: 'leftJoin',
})
})
const countResult = await chainMethods({
methods: chainedMethods,
query: db
.select({
count: count(),
count: useDistinct ? sql`COUNT(DISTINCT ${this.tables[tableName].id})` : count(),
})
.from(this.tables[tableName])
.where(where),