Skip to content

Commit b878daf

Browse files
authored
feat(db-postgres): deep querying on json and rich text fields (#9102)
### What? Allows to query on JSON / Rich Text fields in Postgres the same way as in Mongodb with any nesting level. Example: Data: ```js { json: { array: [ { text: 'some-text', // nested to array + object object: { text: 'deep-text', // nested to array + 2x object array: [10], // number is nested to array + 2x object + array }, }, ], } } ``` Query: ```ts payload.find({ collection: 'json-fields', where: { and: [ { 'json.array.text': { equals: 'some-text', }, }, { 'json.array.object.text': { equals: 'deep-text', }, }, { 'json.array.object.array': { in: [10, 20], }, }, { 'json.array.object.array': { exists: true, }, }, { 'json.array.object.notexists': { exists: false, }, }, ], }, }) ``` ### How? Utilizes [the `jsonb_path_exists` postgres function](https://www.postgresql.org/docs/current/functions-json.html)
1 parent 23907e4 commit b878daf

File tree

11 files changed

+142
-105
lines changed

11 files changed

+142
-105
lines changed

packages/db-postgres/src/index.ts

Lines changed: 0 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -35,7 +35,6 @@ import {
3535
updateVersion,
3636
} from '@payloadcms/drizzle'
3737
import {
38-
convertPathToJSONTraversal,
3938
countDistinct,
4039
createDatabase,
4140
createExtensions,
@@ -125,7 +124,6 @@ export function postgresAdapter(args: Args): DatabaseAdapterObj<PostgresAdapter>
125124
args.transactionOptions === false ? defaultBeginTransaction() : beginTransaction,
126125
commitTransaction,
127126
connect,
128-
convertPathToJSONTraversal,
129127
count,
130128
countDistinct,
131129
countGlobalVersions,

packages/db-vercel-postgres/src/index.ts

Lines changed: 0 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -35,7 +35,6 @@ import {
3535
updateVersion,
3636
} from '@payloadcms/drizzle'
3737
import {
38-
convertPathToJSONTraversal,
3938
countDistinct,
4039
createDatabase,
4140
createExtensions,
@@ -126,7 +125,6 @@ export function vercelPostgresAdapter(args: Args = {}): DatabaseAdapterObj<Verce
126125
args.transactionOptions === false ? defaultBeginTransaction() : beginTransaction,
127126
commitTransaction,
128127
connect,
129-
convertPathToJSONTraversal,
130128
count,
131129
countDistinct,
132130
countGlobalVersions,

packages/drizzle/src/exports/postgres.ts

Lines changed: 0 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,6 @@
11
export { countDistinct } from '../postgres/countDistinct.js'
22
export { createDatabase } from '../postgres/createDatabase.js'
33
export { createExtensions } from '../postgres/createExtensions.js'
4-
export { convertPathToJSONTraversal } from '../postgres/createJSONQuery/convertPathToJSONTraversal.js'
54
export { createJSONQuery } from '../postgres/createJSONQuery/index.js'
65
export { createMigration } from '../postgres/createMigration.js'
76
export { defaultDrizzleSnapshot } from '../postgres/defaultSnapshot.js'

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

Lines changed: 0 additions & 15 deletions
This file was deleted.

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

Lines changed: 0 additions & 3 deletions
This file was deleted.
Lines changed: 32 additions & 76 deletions
Original file line numberDiff line numberDiff line change
@@ -1,87 +1,43 @@
1-
import { convertPathToJSONTraversal } from './convertPathToJSONTraversal.js'
2-
import { formatJSONPathSegment } from './formatJSONPathSegment.js'
3-
4-
const operatorMap = {
5-
contains: '~*',
6-
equals: '=',
7-
like: '~*',
8-
}
9-
10-
type FromArrayArgs = {
11-
isRoot?: true
12-
operator: string
13-
pathSegments: string[]
14-
treatAsArray?: string[]
15-
value: unknown
16-
}
17-
18-
const fromArray = ({ isRoot, operator, pathSegments, treatAsArray, value }: FromArrayArgs) => {
19-
const newPathSegments = pathSegments.slice(isRoot ? 1 : 2)
20-
const alias = `${pathSegments[isRoot ? 0 : 1]}_alias_${newPathSegments.length}`
21-
22-
newPathSegments.unshift(alias)
23-
24-
const arrayElements = isRoot
25-
? pathSegments[0]
26-
: `${pathSegments[0]} -> ${formatJSONPathSegment(pathSegments[1])}`
27-
28-
return `EXISTS (
29-
SELECT 1
30-
FROM jsonb_array_elements(${arrayElements}) AS ${alias}
31-
WHERE ${createJSONQuery({
32-
operator,
33-
pathSegments: newPathSegments,
34-
treatAsArray,
35-
value,
36-
})}
37-
)`
38-
}
39-
40-
type CreateConstraintArgs = {
41-
operator: string
42-
pathSegments: string[]
43-
treatAsArray?: string[]
44-
value: unknown
1+
import type { CreateJSONQueryArgs } from '../../types.js'
2+
3+
const operatorMap: Record<string, string> = {
4+
contains: '~',
5+
equals: '==',
6+
in: 'in',
7+
like: 'like_regex',
8+
not_equals: '!=',
9+
not_in: 'in',
4510
}
4611

47-
const createConstraint = ({ operator, pathSegments, value }: CreateConstraintArgs): string => {
48-
const jsonQuery = convertPathToJSONTraversal(pathSegments)
49-
return `${pathSegments[0]}${jsonQuery} ${operatorMap[operator]} '${value}'`
50-
}
12+
const sanitizeValue = (value: unknown, operator?: string) => {
13+
if (typeof value === 'string') {
14+
// ignore casing with like
15+
return `"${operator === 'like' ? '(?i)' : ''}${value}"`
16+
}
5117

52-
type Args = {
53-
operator: string
54-
pathSegments: string[]
55-
treatAsArray?: string[]
56-
treatRootAsArray?: boolean
57-
value: unknown
18+
return value as string
5819
}
5920

60-
export const createJSONQuery = ({
61-
operator,
62-
pathSegments,
63-
treatAsArray,
64-
treatRootAsArray,
65-
value,
66-
}: Args): string => {
67-
if (treatRootAsArray) {
68-
return fromArray({
69-
isRoot: true,
70-
operator,
71-
pathSegments,
72-
treatAsArray,
73-
value,
21+
export const createJSONQuery = ({ column, operator, pathSegments, value }: CreateJSONQueryArgs) => {
22+
const columnName = typeof column === 'object' ? column.name : column
23+
const jsonPaths = pathSegments
24+
.slice(1)
25+
.map((key) => {
26+
return `${key}[*]`
7427
})
75-
}
28+
.join('.')
29+
30+
let sql = ''
7631

77-
if (treatAsArray.includes(pathSegments[1])) {
78-
return fromArray({
79-
operator,
80-
pathSegments,
81-
treatAsArray,
82-
value,
32+
if (['in', 'not_in'].includes(operator) && Array.isArray(value)) {
33+
value.forEach((item, i) => {
34+
sql = `${sql}${createJSONQuery({ column, operator: operator === 'in' ? 'equals' : 'not_equals', pathSegments, value: item })}${i === value.length - 1 ? '' : ` ${operator === 'in' ? 'OR' : 'AND'} `}`
8335
})
36+
} else if (operator === 'exists') {
37+
sql = `${value === false ? 'NOT ' : ''}jsonb_path_exists(${columnName}, '$.${jsonPaths}')`
38+
} else {
39+
sql = `jsonb_path_exists(${columnName}, '$.${jsonPaths} ? (@ ${operatorMap[operator]} ${sanitizeValue(value, operator)})')`
8440
}
8541

86-
return createConstraint({ operator, pathSegments, treatAsArray, value })
42+
return sql
8743
}

packages/drizzle/src/queries/parseParams.ts

Lines changed: 13 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -103,6 +103,18 @@ export function parseParams({
103103
Array.isArray(pathSegments) &&
104104
pathSegments.length > 1
105105
) {
106+
if (adapter.name === 'postgres') {
107+
const constraint = adapter.createJSONQuery({
108+
column: rawColumn || table[columnName],
109+
operator,
110+
pathSegments,
111+
value: val,
112+
})
113+
114+
constraints.push(sql.raw(constraint))
115+
break
116+
}
117+
106118
const segments = pathSegments.slice(1)
107119
segments.unshift(table[columnName].name)
108120

@@ -142,11 +154,7 @@ export function parseParams({
142154
if (adapter.name === 'sqlite' && operator === 'equals' && !isNaN(val)) {
143155
formattedValue = val
144156
} else if (['in', 'not_in'].includes(operator) && Array.isArray(val)) {
145-
if (adapter.name === 'sqlite') {
146-
formattedValue = `(${val.map((v) => `${v}`).join(',')})`
147-
} else {
148-
formattedValue = `(${val.map((v) => `'${v}'`).join(', ')})`
149-
}
157+
formattedValue = `(${val.map((v) => `${v}`).join(',')})`
150158
} else {
151159
formattedValue = `'${operatorKeys[operator].wildcard}${val}${operatorKeys[operator].wildcard}'`
152160
}

packages/drizzle/src/types.ts

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,5 @@
11
import type {
2+
Column,
23
ColumnBaseConfig,
34
ColumnDataType,
45
DrizzleConfig,
@@ -148,6 +149,7 @@ export type Migration = {
148149
} & MigrationData
149150

150151
export type CreateJSONQueryArgs = {
152+
column?: Column | string
151153
operator: string
152154
pathSegments: string[]
153155
table?: string
@@ -157,7 +159,7 @@ export type CreateJSONQueryArgs = {
157159
}
158160

159161
export interface DrizzleAdapter extends BaseDatabaseAdapter {
160-
convertPathToJSONTraversal: (incomingSegments: string[]) => string
162+
convertPathToJSONTraversal?: (incomingSegments: string[]) => string
161163
countDistinct: CountDistinct
162164
createJSONQuery: (args: CreateJSONQueryArgs) => string
163165
defaultDrizzleSnapshot: Record<string, unknown>

test/fields/collections/JSON/index.tsx

Lines changed: 27 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -19,6 +19,33 @@ const JSON: CollectionConfig = {
1919
schema: {
2020
type: 'object',
2121
properties: {
22+
array: {
23+
type: 'array',
24+
items: {
25+
type: 'object',
26+
additionalProperties: false,
27+
properties: {
28+
object: {
29+
type: 'object',
30+
additionalProperties: false,
31+
properties: {
32+
array: {
33+
type: 'array',
34+
items: {
35+
type: 'number',
36+
},
37+
},
38+
text: {
39+
type: 'string',
40+
},
41+
},
42+
},
43+
text: {
44+
type: 'string',
45+
},
46+
},
47+
},
48+
},
2249
foo: {
2350
enum: ['bar', 'foobar'],
2451
},

test/fields/int.spec.ts

Lines changed: 60 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2657,6 +2657,66 @@ describe('Fields', () => {
26572657
expect(docIDs).not.toContain(3)
26582658
expect(docIDs).toContain(2)
26592659
})
2660+
2661+
it('should query deeply', async () => {
2662+
// eslint-disable-next-line jest/no-conditional-in-test
2663+
if (payload.db.name === 'sqlite') {
2664+
return
2665+
}
2666+
2667+
const json_1 = await payload.create({
2668+
collection: 'json-fields',
2669+
data: {
2670+
json: {
2671+
array: [
2672+
{
2673+
text: 'some-text',
2674+
object: {
2675+
text: 'deep-text',
2676+
array: [10],
2677+
},
2678+
},
2679+
],
2680+
},
2681+
},
2682+
})
2683+
2684+
const { docs } = await payload.find({
2685+
collection: 'json-fields',
2686+
where: {
2687+
and: [
2688+
{
2689+
'json.array.text': {
2690+
equals: 'some-text',
2691+
},
2692+
},
2693+
{
2694+
'json.array.object.text': {
2695+
equals: 'deep-text',
2696+
},
2697+
},
2698+
{
2699+
'json.array.object.array': {
2700+
in: [10, 20],
2701+
},
2702+
},
2703+
{
2704+
'json.array.object.array': {
2705+
exists: true,
2706+
},
2707+
},
2708+
{
2709+
'json.array.object.notexists': {
2710+
exists: false,
2711+
},
2712+
},
2713+
],
2714+
},
2715+
})
2716+
2717+
expect(docs).toHaveLength(1)
2718+
expect(docs[0].id).toBe(json_1.id)
2719+
})
26602720
})
26612721
})
26622722

0 commit comments

Comments
 (0)