Skip to content

Commit 207295b

Browse files
authored
fix(drizzle): postgesql where in jsonb (#13742)
### What? - Adds a test for using `and` and `in` clauses on `json` fields. - Fixes the failing test for posgresql db due to faulty logic in the `drizzle` package. ### Why? When querying the jobs queue, I discovered it returned jobs it should not, but only when using the `in` clause. Enabling statement logs in postgresql helped me find the underlying issue. This query, when passed to the local API: ```ts { and: [ { taskSlug: { equals: 'schedulePublish', }, }, { waitUntil: { greater_than: new Date(), }, }, { 'input.doc.value': { in: ids.map(String), }, }, { 'input.doc.relationTo': { equals: 'example', }, }, ], } ``` generated this SQL where clause: ```sql where ( "payload_jobs"."task_slug" = $1 and "payload_jobs"."wait_until" > $2 and jsonb_path_exists(input, '$.doc[*].value[*] ? (@ == "22")') OR jsonb_path_exists(input, '$.doc[*].value[*] ? (@ == "25")') and jsonb_path_exists( input, '$.doc[*].relationTo[*] ? (@ == "alerts")' ) ) ``` which returns items that only pass the first 3 clauses `OR` the last 2. Instead, the query should be ```sql where ( "payload_jobs"."task_slug" = $1 and "payload_jobs"."wait_until" > $2 and ( jsonb_path_exists(input, '$.doc[*].value[*] ? (@ == "22")') OR jsonb_path_exists(input, '$.doc[*].value[*] ? (@ == "25")') ) and jsonb_path_exists( input, '$.doc[*].relationTo[*] ? (@ == "alerts")' ) ) ``` ### How? By adding parens around the generated `AND`/`OR` clauses for `in` statements on `json` columns with the postgresql backeend, it fixes the faulty logic.
1 parent ff670c0 commit 207295b

File tree

2 files changed

+30
-1
lines changed

2 files changed

+30
-1
lines changed

packages/drizzle/src/postgres/createJSONQuery/index.ts

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -33,9 +33,11 @@ export const createJSONQuery = ({ column, operator, pathSegments, value }: Creat
3333
let sql = ''
3434

3535
if (['in', 'not_in'].includes(operator) && Array.isArray(value)) {
36+
sql = '('
3637
value.forEach((item, i) => {
3738
sql = `${sql}${createJSONQuery({ column, operator: operator === 'in' ? 'equals' : 'not_equals', pathSegments, value: item })}${i === value.length - 1 ? '' : ` ${operator === 'in' ? 'OR' : 'AND'} `}`
3839
})
40+
sql = `${sql})`
3941
} else if (operator === 'exists') {
4042
sql = `${value === false ? 'NOT ' : ''}jsonb_path_exists(${columnName}, '${fullPath}')`
4143
} else if (['not_like'].includes(operator)) {

test/fields/int.spec.ts

Lines changed: 28 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -3168,7 +3168,10 @@ describe('Fields', () => {
31683168
await payload.create({
31693169
collection: 'json-fields',
31703170
data: {
3171-
json: { value: i },
3171+
json: {
3172+
value: i,
3173+
isEven: i % 2 === 0,
3174+
},
31723175
},
31733176
})
31743177
}
@@ -3374,6 +3377,30 @@ describe('Fields', () => {
33743377
expect(docIDs).toContain(2)
33753378
})
33763379

3380+
it('should query nested numbers with multiple clauses - equals_and_in', async () => {
3381+
const { docs } = await payload.find({
3382+
collection: 'json-fields',
3383+
where: {
3384+
and: [
3385+
{
3386+
'json.isEven': { equals: true },
3387+
},
3388+
{
3389+
// Tests odd -> even order and even -> odd order for better coverage.
3390+
'json.value': { in: [1, 4, 2, 3] },
3391+
},
3392+
],
3393+
},
3394+
})
3395+
3396+
const docIDs = docs.map(({ json }) => json.value)
3397+
3398+
expect(docIDs).not.toContain(1)
3399+
expect(docIDs).toContain(2)
3400+
expect(docIDs).not.toContain(3)
3401+
expect(docIDs).toContain(4)
3402+
})
3403+
33773404
it('should query deeply', async () => {
33783405
// eslint-disable-next-line jest/no-conditional-in-test
33793406
if (payload.db.name === 'sqlite') {

0 commit comments

Comments
 (0)