forked from sqlpage/SQLPage
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy path50_blog_json.sql
585 lines (433 loc) · 15.4 KB
/
50_blog_json.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
INSERT INTO blog_posts (title, description, icon, created_at, content)
VALUES
(
'JSON in SQL: A Comprehensive Guide',
'A comprehensive guide to working with JSON data in SQLite, PostgreSQL, MySQL, and SQL Server.',
'braces',
'2024-09-03',
'
# JSON in SQL: A Comprehensive Guide
## Introduction
JSON (JavaScript Object Notation) is a popular data format for unstructured data. It allows storing composite data types, such as arrays and objects, in a single SQL value.
Many modern applications use JSON to store and exchange data. As a result, SQL databases have incorporated JSON support to allow developers to work with structured and semi-structured data within the same database.
This guide will cover JSON operations in SQLite, PostgreSQL, MySQL, and SQL Server, focusing on querying JSON data.
SQLPage uses JSON both to pass data to the database (when a SQLPage variable contains an array), and to pass data to components (when a component has a JSON parameter).
Thus, understanding how to work with JSON in SQL will allow you to fully leverage advanced SQLPage features.
JSON supports the following data types:
- **Objects**: A mapping between keys and values (`{ "key": "value" }`). Keys must be strings, and values can be of different types.
- **Arrays**: An ordered list of values enclosed in square brackets (`[ "value1", "value2" ]`). Values can be of different types.
- **Strings**: A sequence of characters enclosed in double quotes (`"Hello, World!"`).
- **Numbers**: An integer or floating-point number (`42`, `3.14`).
- **Boolean**: A true or false value (`true`, `false`).
- **Null**: A null value (`null`).
## Sample Table
We''ll use the following sample table for our examples:
```sql
CREATE TABLE users (
id INT PRIMARY KEY,
name VARCHAR(50),
birthday DATE,
group_name VARCHAR(50)
);
INSERT INTO users (id, name, birthday, group_name) VALUES
(1, ''Alice'', ''1990-01-15'', ''Admin''),
(2, ''Bob'', ''1985-05-22'', ''User''),
(3, ''Charlie'', ''1992-09-30'', ''User'');
```
## SQLite
SQLite provides increasingly better JSON support since version 3.38.0.
See [the list of JSON functions in SQLite](https://www.sqlite.org/json1.html) for more details.
### Creating a JSON object
We can use the standard `json_object()` function to create a JSON object from columns in a table:
```sql
SELECT json_object(''name'', name, ''birthday'', birthday) AS user_json
FROM users;
```
| user_json |
|-----------|
| `{"name":"Alice","birthday":"1990-01-15"}` |
| `{"name":"Bob","birthday":"1985-05-22"}` |
| `{"name":"Charlie","birthday":"1992-09-30"}` |
### Creating a JSON array
```sql
SELECT json_array(name, birthday, group_name) AS user_array
FROM users;
```
| user_array |
|------------|
| `["Alice","1990-01-15","Admin"]` |
| `["Bob","1985-05-22","User"]` |
| `["Charlie","1992-09-30","User"]` |
### Aggregating multiple values into a JSON array
```sql
SELECT json_group_array(name) AS names
FROM users;
```
| names |
|-------|
| `["Alice","Bob","Charlie"]` |
### Aggregating values into a JSON object
```sql
SELECT json_group_object(name, group_name) AS name_group_map
FROM users;
```
| name_group_map |
|-------------------|
| `{"Alice":"Admin", "Bob":"User", "Charlie":"User"}` |
### Iterating over a JSON array
SQLite provides the `json_each()` table-valued function to iterate over JSON arrays. This function returns one row for each element in the JSON array.
```sql
SELECT value FROM json_each(''["Alice", "Bob", "Charlie"]'');
```
| value |
|-------|
| Alice |
| Bob |
| Charlie |
The `json_each()` function returns a table with several columns. The most commonly used are:
- `key`: The array index (0-based) for elements of a JSON array
- `value`: The value of the current element
- `type`: The type of the current element (e.g., ''text'', ''integer'', ''real'', ''true'', ''false'', ''null'')
For more complex JSON structures, you can use the `json_tree()` function, which recursively walks through the entire JSON structure.
These iteration functions can be used to check if specific values exist in a JSON array.
Here''s a practical example:
Let''s say you have a form with a [multiple-choice dropdown](documentation.sql?component=form#component) that allows selecting multiple users.
Some users might already be selected, and their IDs are stored in a JSON array passed as an URL parameter called `$selected_ids`.
You can create this dropdown using the following query:
```sql
select json_group_array(json_object(
''label'', name,
''value'', id,
''selected'', id in (select value from json_each_text($selected_ids))
)) as options
from users;
```
This query will:
1. Create a dropdown option for each user
2. Use their name as the display label
3. Use their ID as the value
4. Mark the option as selected if the user''s ID exists in the $selected_ids array
### Combining two JSON objects
SQLite provides the `json_patch()` function to combine two JSON objects. This function takes two JSON objects as arguments and returns a new JSON object that is the result of merging the two input objects.
```sql
SELECT json_patch(''{"name": "Alice"}'', ''{"birthday": "1990-01-15"}'') AS user_json;
```
| user_json |
|-----------|
| {"name": "Alice", "birthday": "1990-01-15"} |
## PostgreSQL
PostgreSQL has extensive support for JSON, including the `jsonb` type, which offers better performance and more functionality than the `json` type.
See [the list of JSON functions in PostgreSQL](https://www.postgresql.org/docs/current/functions-json.html) for more details.
### Creating a JSON object
```sql
SELECT
jsonb_build_object(
''name'', name,
''birthday'', birthday
) AS user_json
FROM users;
```
| user_json |
|-----------|
| `{"name":"Alice","birthday":"1990-01-15"}` |
| `{"name":"Bob","birthday":"1985-05-22"}` |
| `{"name":"Charlie","birthday":"1992-09-30"}` |
### Creating a JSON array
```sql
SELECT
jsonb_build_array(
name, birthday, group_name
) AS user_array
FROM users;
```
| user_array |
|------------|
| `["Alice", "1990-01-15", "Admin"]` |
| `["Bob", "1985-05-22", "User"]` |
| `["Charlie", "1992-09-30", "User"]` |
### Aggregating multiple values into a JSON array
```sql
SELECT jsonb_agg(name) AS names FROM users;
```
| names |
|-------|
| `["Alice","Bob","Charlie"]` |
### Aggregating values into a JSON object
```sql
SELECT
jsonb_object_agg(
name, birthday
) AS name_birthday_map
FROM users;
```
| name_birthday_map |
|-------------------|
| `{"Alice":"1990-01-15","Bob":"1985-05-22","Charlie":"1992-09-30"}` |
### Iterating over a JSON array
```sql
SELECT name FROM jsonb_array_elements_text(''["Alice", "Bob", "Charlie"]''::jsonb) AS name;
```
| name |
|------|
| Alice |
| Bob |
| Charlie |
You can use this function to test whether a value is present in a JSON array. For instance, to create a
[multi-value select dropdown](documentation.sql?component=form#component) with pre-selected values, you can use the following query:
```sql
SELECT jsonb_agg(jsonb_build_object(
''label'', name,
''value'', id,
''selected'', id in (SELECT value FROM jsonb_array_elements_text($selected_ids::jsonb))
)) AS options
FROM users;
```
### Iterating over a JSON object
```sql
SELECT key, value
FROM jsonb_each_text(''{"name": "Alice", "birthday": "1990-01-15"}''::jsonb);
```
| key | value |
|-----|-------|
| name | Alice |
| birthday | 1990-01-15 |
### Querying JSON data
PostgreSQL allows you to query JSON data using the `->` and `->>` operators:
```sql
SELECT name, user_data->>''age'' AS age
FROM (
SELECT name, jsonb_build_object(''age'', EXTRACT(YEAR FROM AGE(birthday))) AS user_data
FROM users
) subquery
WHERE (user_data->>''age'')::int > 30;
```
| name | age |
|------|-----|
| Bob | 38 |
### Combining two JSON objects
PostgreSQL provides the `||` operator to combine two JSON objects.
```sql
SELECT ''{"name": "Alice"}''::jsonb || ''{"birthday": "1990-01-15"}''::jsonb AS user_json;
```
| user_json |
|-----------|
| {"name": "Alice", "birthday": "1990-01-15"} |
## MySQL / MariaDB
MySQL has good support for JSON operations starting from version 5.7.
See [the list of JSON functions in MySQL](https://dev.mysql.com/doc/refman/8.0/en/json-functions.html) for more details.
### Creating a JSON object
```sql
SELECT JSON_OBJECT(''name'', name, ''birthday'', birthday) AS user_json
FROM users;
```
| user_json |
|-----------|
| `{"name":"Alice","birthday":"1990-01-15"}` |
| `{"name":"Bob","birthday":"1985-05-22"}` |
| `{"name":"Charlie","birthday":"1992-09-30"}` |
### Creating a JSON array
```sql
SELECT JSON_ARRAY(name, birthday, group_name) AS user_array
FROM users;
```
| user_array |
|------------|
| `["Alice","1990-01-15","Admin"]` |
| `["Bob","1985-05-22","User"]` |
| `["Charlie","1992-09-30","User"]` |
### Aggregating multiple values into a JSON array
```sql
SELECT JSON_ARRAYAGG(name) AS names
FROM users;
```
| names |
|-------|
| `["Alice","Bob","Charlie"]` |
### Aggregating values into a JSON object
```sql
SELECT JSON_OBJECTAGG(name, birthday) AS name_birthday_map
FROM users;
```
| name_birthday_map |
|-------------------|
| `{"Alice":"1990-01-15","Bob":"1985-05-22","Charlie":"1992-09-30"}` |
### Iterating over a JSON array
MySQL provides the JSON_TABLE() function to iterate over JSON arrays. This powerful function allows you to convert JSON data into a relational table format, making it easy to work with JSON arrays.
Here''s an example of how to use JSON_TABLE() to iterate over a JSON array:
```sql
SELECT jt.name
FROM JSON_TABLE(
''["Alice", "Bob", "Charlie"]'',
''$[*]'' COLUMNS( name VARCHAR(50) PATH ''$'' )
) AS jt;
```
| name |
|---------|
| Alice |
| Bob |
| Charlie |
In this example:
- The first argument to JSON_TABLE() is the JSON array.
- `''$[*]''` is the path expression that selects all elements of the array.
- The `COLUMNS` clause defines the structure of the output table. In our case, we want a single column named `name`:
- `name VARCHAR(50) PATH ''$''` creates a text column that contains the raw value of each array element in its entirety (`$` is the current element).
You can also use JSON_TABLE() with more complex JSON structures:
```sql
SELECT jt.*
FROM JSON_TABLE(
''[{"id": 1, "name": "Alice"}, {"id": 2, "name": "Bob"}, {"id": 3, "name": "Charlie"}]'',
''$[*]'' COLUMNS(
id INT PATH ''$.id'',
name VARCHAR(50) PATH ''$.name''
)
) AS jt;
```
| id | name |
|----|---------|
| 1 | Alice |
| 2 | Bob |
| 3 | Charlie |
This approach allows you to easily iterate over JSON arrays and access their elements in a tabular format, which can be very useful for further processing or joining with other tables in your database.
### Iterating over a JSON object
The `JSON_TABLE` function can also be used to iterate over JSON objects:
```sql
SELECT jt.*
FROM JSON_TABLE(
''{"name": "Alice", "birthday": "1990-01-15"}'',
''$.*'' COLUMNS (
value JSON PATH ''$''
)
) AS jt;
```
| value |
|-------|
| "Alice" |
| "1990-01-15" |
#### Iterating over key-value pairs
You can use the `JSON_KEYS()` function to retrieve the list of keys in a JSON object as a JSON array,
then use that array to iterate over the keys of a JSON object:
```sql
SELECT json_key, json_extract(json_str, CONCAT(''$.'', json_key)) as json_value
FROM
(select ''{"name": "Alice", "birthday": "1990-01-15"}'' as json_str) AS my_json,
JSON_TABLE(json_keys(json_str), ''$[*]'' COLUMNS (json_key JSON PATH ''$'')) AS json_keys;
```
| json_key | json_value |
|----------|------------|
| name | Alice |
| birthday | 1990-01-15 |
### Querying JSON data
MySQL allows you to query JSON data using the `->` and `->>` operators:
```sql
SELECT name, user_data->''$.age'' AS age
FROM (
SELECT name, JSON_OBJECT(''age'', YEAR(CURDATE()) - YEAR(birthday)) AS user_data
FROM users
) subquery
WHERE user_data->''$.age'' > 30;
```
| name | age |
|------|-----|
| Bob | 38 |
## Microsoft SQL Server
SQL Server has support for JSON operations starting from SQL Server 2016.
See [the list of JSON functions in SQL Server](https://learn.microsoft.com/en-us/sql/t-sql/functions/json-functions-transact-sql?view=sql-server-ver16) for more details.
# JSON in SQL: A Comprehensive Guide
[Previous sections remain unchanged]
## Microsoft SQL Server
SQL Server has support for JSON operations starting from SQL Server 2016. It provides a comprehensive set of functions for working with JSON data.
See [the list of JSON functions in SQL Server](https://learn.microsoft.com/en-us/sql/t-sql/functions/json-functions-transact-sql?view=sql-server-ver16) for more details.
### Creating a JSON object
Use the `FOR JSON PATH` clause to create a JSON object:
```sql
SELECT (SELECT name, birthday FOR JSON PATH, WITHOUT_ARRAY_WRAPPER) AS user_json
FROM users;
```
| user_json |
|-----------|
| `{"name":"Alice","birthday":"1990-01-15"}` |
| `{"name":"Bob","birthday":"1985-05-22"}` |
| `{"name":"Charlie","birthday":"1992-09-30"}` |
Alternatively, you can use the `JSON_OBJECT` function:
```sql
SELECT JSON_OBJECT(''name'': name, ''birthday'': birthday) AS user_json
FROM users;
```
### Creating a JSON array
Use the `FOR JSON PATH` clause to create a JSON array:
```sql
SELECT (SELECT name, birthday, group_name FOR JSON PATH) AS user_array
FROM users;
```
| user_array |
|------------|
| `[{"name":"Alice","birthday":"1990-01-15","group_name":"Admin"}]` |
| `[{"name":"Bob","birthday":"1985-05-22","group_name":"User"}]` |
| `[{"name":"Charlie","birthday":"1992-09-30","group_name":"User"}]` |
You can also use the `JSON_ARRAY` function:
```sql
SELECT JSON_ARRAY(name, birthday, group_name) AS user_array
FROM users;
```
### Aggregating multiple values into a JSON array
Use the `FOR JSON PATH` clause to aggregate values into a JSON array:
```sql
SELECT (SELECT name FROM users FOR JSON PATH) AS names;
```
| names |
|-------|
| `[{"name":"Alice"},{"name":"Bob"},{"name":"Charlie"}]` |
Alternatively, use the `JSON_ARRAYAGG` function:
```sql
SELECT JSON_ARRAYAGG(name) AS names FROM users;
```
### Aggregating values into a JSON object
```sql
SELECT JSON_OBJECTAGG(name: birthday) AS name_birthday_map FROM users;
```
### Iterating over a JSON array
Use the `OPENJSON` function to iterate over JSON arrays:
```sql
SELECT value FROM OPENJSON(''["Alice", "Bob", "Charlie"]'');
```
| value |
|-------|
| Alice |
| Bob |
| Charlie |
### Iterating over a JSON object
Use `OPENJSON` to iterate over JSON objects:
```sql
SELECT *
FROM OPENJSON(''{"name": "Alice", "birthday": "1990-01-15"}'')
WITH (
name NVARCHAR(50) ''$.name'',
birthday DATE ''$.birthday''
);
```
| name | birthday |
|------|----------|
| Alice | 1990-01-15 |
### Querying JSON data
Use the `JSON_VALUE` function to extract scalar values from JSON:
```sql
SELECT JSON_VALUE(''{"age": 38}'', ''$.age'') AS age
```
| age |
|-----|
| 38 |
### Additional JSON Functions
SQL Server provides several other useful JSON functions:
- `ISJSON`: Tests whether a string contains valid JSON.
- `JSON_MODIFY`: Updates the value of a property in a JSON string.
- `JSON_PATH_EXISTS`: Tests whether a specified SQL/JSON path exists in the input JSON string.
- `JSON_QUERY`: Extracts an object or an array from a JSON string.
Example using `JSON_MODIFY`:
```sql
SELECT JSON_MODIFY(''{"name": "Alice", "age": 30}'', ''$.age'', 31) AS updated_json;
```
| updated_json |
|--------------|
| {"name": "Alice", "age": 31} |
This comprehensive guide covers the basics of working with JSON in SQLite, PostgreSQL, MySQL, and SQL Server. Each database has its own set of functions and syntax for JSON operations, but the general concepts remain similar across all platforms.
');