Skip to content

Commit 1dff614

Browse files
committed
Add unit tests and documentation on json operations
1 parent da3f6c7 commit 1dff614

File tree

3 files changed

+288
-0
lines changed

3 files changed

+288
-0
lines changed

docs/.vitepress/config.mts

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -30,6 +30,7 @@ export default defineConfig({
3030
{ text: 'Introduction', link: '/introduction' },
3131
{ text: 'Basic Queries', link: '/basic-queries' },
3232
{ text: 'Advanced Queries', link: '/advanced-queries' },
33+
{ text: 'JSON Queries', link: '/json-queries' },
3334
{ text: 'Background Writes', link: '/background-writes' },
3435
{ text: 'Migrations', link: '/migrations' },
3536
{ text: 'Type Checking', link: '/type-check' },

docs/json-queries.md

Lines changed: 142 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,142 @@
1+
---
2+
title: JSON Queries
3+
description: How to query JSON fields in workers-qb.
4+
---
5+
6+
# Querying JSON Fields
7+
8+
`workers-qb` takes advantage of the powerful JSON querying capabilities of the underlying database engines, especially Cloudflare D1. This allows you to efficiently work with JSON data stored in your database.
9+
10+
JSON data is typically stored in a `TEXT` column. You can then use a variety of functions to manipulate and query this data directly in your SQL queries.
11+
12+
## Extracting Values
13+
14+
You can extract values from a JSON object using `json_extract`, `->`, and `->>`.
15+
16+
- `json_extract(json, path)`: Extracts a value from a JSON object at a given path.
17+
- `->`: Extracts a value as a JSON object.
18+
- `->>`: Extracts a value as a SQL type.
19+
20+
```typescript
21+
// Example JSON object stored in a 'data' column:
22+
// { "name": "John Doe", "age": 30, "is_active": true, "tags": ["a", "b"] }
23+
24+
// Using json_extract
25+
const user = await qb.fetchOne({
26+
tableName: 'users',
27+
fields: ["json_extract(data, '$.name') as name"],
28+
where: { conditions: 'id = ?', params: 1 },
29+
}).execute();
30+
// user.results.name will be "John Doe"
31+
32+
// Using ->>
33+
const user = await qb.fetchOne({
34+
tableName: 'users',
35+
fields: ["data ->> '$.name' as name"],
36+
where: { conditions: 'id = ?', params: 1 },
37+
}).execute();
38+
// user.results.name will be "John Doe"
39+
```
40+
41+
## Array Operations
42+
43+
### Get Array Length
44+
45+
Use `json_array_length` to get the number of elements in a JSON array.
46+
47+
```typescript
48+
// data column: { "tags": ["a", "b", "c"] }
49+
50+
const tagCount = await qb.fetchOne({
51+
tableName: 'posts',
52+
fields: ["json_array_length(data, '$.tags') as count"],
53+
where: { conditions: 'id = ?', params: 1 },
54+
}).execute();
55+
// tagCount.results.count will be 3
56+
```
57+
58+
### Expand Arrays for `IN` Queries
59+
60+
`json_each` can be used to expand a JSON array into a set of rows, which is useful for `IN` clauses.
61+
62+
```typescript
63+
const userIds = [1, 2, 3];
64+
const users = await qb.fetchAll({
65+
tableName: 'users',
66+
where: {
67+
conditions: `id IN (SELECT value FROM json_each(?))`,
68+
params: [JSON.stringify(userIds)],
69+
},
70+
}).execute();
71+
```
72+
73+
## Modifying JSON Data
74+
75+
### Insert, Replace, and Set
76+
77+
- `json_insert(json, path, value)`: Inserts a value at a given path. Does not overwrite existing values.
78+
- `json_replace(json, path, value)`: Replaces an existing value at a given path.
79+
- `json_set(json, path, value)`: Sets a value at a given path, overwriting if it exists or creating if it does not.
80+
81+
```typescript
82+
import { Raw } from 'workers-qb';
83+
84+
// data column: { "name": "John Doe" }
85+
86+
// Using json_set to add an age
87+
// We wrap the SQL function in `new Raw()` to tell the query builder to treat it as a raw expression.
88+
await qb.update({
89+
tableName: 'users',
90+
data: {
91+
data: new Raw(`json_set(data, '$.age', 30)`),
92+
},
93+
where: { conditions: 'id = ?', params: 1 },
94+
}).execute();
95+
// data column is now: { "name": "John Doe", "age": 30 }
96+
```
97+
98+
## Creating JSON
99+
100+
You can create JSON objects and arrays directly in your queries.
101+
102+
- `json_object(label1, value1, ...)`: Creates a JSON object from key-value pairs.
103+
- `json_array(value1, value2, ...)`: Creates a JSON array.
104+
105+
```typescript
106+
const result = await qb.fetchOne({
107+
tableName: 'users', // This can be any table
108+
fields: ["json_object('name', 'John', 'age', 30) as json_data"],
109+
}).execute();
110+
// result.results.json_data will be { "name": "John", "age": 30 }
111+
```
112+
113+
## Other Useful Functions
114+
115+
- `json_type(json, path)`: Returns the type of a JSON value.
116+
- `json_valid(json)`: Checks if a string is valid JSON.
117+
- `json_quote(value)`: Converts a SQL value to its JSON representation.
118+
119+
```typescript
120+
// json_type
121+
const user = await qb.fetchOne({
122+
tableName: 'users',
123+
fields: ["json_type(data, '$.age') as ageType"],
124+
where: { conditions: 'id = ?', params: 1 },
125+
}).execute();
126+
// user.results.ageType will be 'integer'
127+
128+
// json_valid
129+
const result = await qb.fetchOne({
130+
tableName: 'users', // This can be any table
131+
fields: ["json_valid('{\"a\":1}') as isValid"],
132+
}).execute();
133+
// result.results.isValid will be 1 (true)
134+
135+
// json_quote
136+
const result = await qb.fetchOne({
137+
tableName: 'users', // This can be any table
138+
fields: ["json_quote('[1, 2, 3]') as json_string"],
139+
}).execute();
140+
// result.results.json_string will be "[1,2,3]"
141+
142+

tests/integration/json.test.ts

Lines changed: 145 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,145 @@
1+
import { env } from 'cloudflare:test'
2+
import { describe, expect, it } from 'vitest'
3+
import { D1QB, Raw } from '../../src'
4+
5+
describe('JSON operations', () => {
6+
it('should perform all json operations correctly', async () => {
7+
const qb = new D1QB(env.DB)
8+
9+
// Setup table
10+
await qb.dropTable({ tableName: 'json_test', ifExists: true }).execute()
11+
await qb
12+
.createTable({
13+
tableName: 'json_test',
14+
schema: 'id INTEGER PRIMARY KEY, data TEXT',
15+
})
16+
.execute()
17+
18+
// Insert test data
19+
await qb
20+
.insert({
21+
tableName: 'json_test',
22+
data: {
23+
id: 1,
24+
data: JSON.stringify({
25+
name: 'John Doe',
26+
age: 30,
27+
is_active: true,
28+
tags: ['a', 'b'],
29+
}),
30+
},
31+
})
32+
.execute()
33+
34+
// Test Extracting Values
35+
const user = await qb
36+
.fetchOne({
37+
tableName: 'json_test',
38+
fields: ["json_extract(data, '$.name') as name"],
39+
where: { conditions: 'id = ?', params: [1] },
40+
})
41+
.execute()
42+
expect(user.results?.name).toBe('John Doe')
43+
44+
const user2 = await qb
45+
.fetchOne({
46+
tableName: 'json_test',
47+
fields: ["data ->> '$.name' as name"],
48+
where: { conditions: 'id = ?', params: [1] },
49+
})
50+
.execute()
51+
expect(user2.results?.name).toBe('John Doe')
52+
53+
// Test Array Operations
54+
const tagCount = await qb
55+
.fetchOne({
56+
tableName: 'json_test',
57+
fields: ["json_array_length(data, '$.tags') as count"],
58+
where: { conditions: 'id = ?', params: [1] },
59+
})
60+
.execute()
61+
expect(tagCount.results?.count).toBe(2)
62+
63+
// Test Modifying JSON Data
64+
await qb
65+
.update({
66+
tableName: 'json_test',
67+
data: {
68+
data: new Raw(`json_set(data, '$.age', 31)`),
69+
},
70+
where: { conditions: 'id = ?', params: [1] },
71+
})
72+
.execute()
73+
74+
const updatedUser = await qb
75+
.fetchOne({
76+
tableName: 'json_test',
77+
fields: ["json_extract(data, '$.age') as age"],
78+
where: { conditions: 'id = ?', params: [1] },
79+
})
80+
.execute()
81+
expect(updatedUser.results?.age).toBe(31)
82+
83+
// Test Creating JSON
84+
const createdJson = await qb
85+
.fetchOne({
86+
tableName: 'json_test',
87+
fields: ["json_object('name', 'Jane', 'age', 25) as json_data"],
88+
})
89+
.execute()
90+
expect(createdJson.results?.json_data).toBe('{"name":"Jane","age":25}')
91+
92+
// Test Other Useful Functions
93+
const ageType = await qb
94+
.fetchOne({
95+
tableName: 'json_test',
96+
fields: ["json_type(data, '$.age') as type"],
97+
where: { conditions: 'id = ?', params: [1] },
98+
})
99+
.execute()
100+
expect(ageType.results?.type).toBe('integer')
101+
102+
const isValid = await qb
103+
.fetchOne({
104+
tableName: 'json_test',
105+
fields: ['json_valid(\'{"a":1}\') as valid'],
106+
})
107+
.execute()
108+
expect(isValid.results?.valid).toBe(1)
109+
110+
const jsonString = await qb
111+
.fetchOne({
112+
tableName: 'json_test',
113+
fields: ["json_quote('[1, 2, 3]') as json_string"],
114+
})
115+
.execute()
116+
expect(jsonString.results?.json_string).toBe('"[1, 2, 3]"')
117+
118+
// Test Expand Arrays for IN Queries
119+
await qb
120+
.insert({
121+
tableName: 'json_test',
122+
data: [
123+
{ id: 2, data: '{}' },
124+
{ id: 3, data: '{}' },
125+
{ id: 4, data: '{}' },
126+
],
127+
})
128+
.execute()
129+
130+
const userIds = [1, 2, 3]
131+
const users = await qb
132+
.fetchAll({
133+
tableName: 'json_test',
134+
where: {
135+
conditions: `id IN (SELECT value FROM json_each(?))`,
136+
params: [JSON.stringify(userIds)],
137+
},
138+
})
139+
.execute()
140+
expect(users.results).toHaveLength(3)
141+
142+
// Cleanup
143+
await qb.dropTable({ tableName: 'json_test' }).execute()
144+
})
145+
})

0 commit comments

Comments
 (0)