Skip to content

Commit 2110d89

Browse files
committed
Update Patterns JSON SQL Interface.md
1 parent b890378 commit 2110d89

File tree

1 file changed

+170
-0
lines changed

1 file changed

+170
-0
lines changed

Patterns JSON SQL Interface.md

Lines changed: 170 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -5,3 +5,173 @@ nav_order: 4
55
parent: Design Patterns
66
permalink: /patterns/json-sql
77
---
8+
9+
The JSON is a popular and robust format for passing structured information in text form. JSON libraries are broadly available in various environments, including RDBMS engines. The JSON format can serve as a kind of SQL interface for parameterized queries. When an application needs to pass a 1D vector of arbitrary length to the script, it is impossible to have a fixed parameterized script with dedicated query parameters assigned to individual values. Instead, the application packs the data into the JSON format and passes these data in a single string query parameter. The SQL script, in turn, incorporates the code for unpacking the JSON format before further processing.
10+
11+
JSON encoding of the passed data has several benefits. It permits having a fixed SQL script accepting an array of arbitrary length as a query parameter. Also, it establishes a relatively simple, robust, and well-defined SQL interface based on a broadly supported format. Finally, because each query parameter may cost an additional API call, this approach may also improve the overall performance of the database call. For the same reasons, using JSON for encoding the returned data may be more efficient than using a record set. While SQLite API calls are usually fast, each returned value still costs several API calls in SQLite. (Under certain circumstances, however, there might be a high SQLite-independent overhead for each API call.) An important consideration to bear in mind related to the JSON containers is the potential side effects of data conversion between numeric and textual formats.
12+
13+
Consider a table *fs_objects(bin_id, prefix, name)* containing a list of file system objects, uniquely identified by their absolute paths (*prefix* || *path_sep* || *name*) and a unique *bin_id*. Suppose an application needs to pass a set of new objects for insertion into this table. Such a set is a 1D vector of arbitrary size, which may contain:
14+
15+
1. **a scalar value for a single column** (e.g., absolute path).
16+
2. **a pair of scalar values for two columns** (e.g., id and absolute path)
17+
3. **a 1D array of attribute-value pairs for multiple columns** (e.g., bin_id, prefix, name)
18+
19+
For each of the three formats, we need a parameterized query accepting an arbitrary length 1D vector as input (query code and the number of query parameters must not depend on the input length). This task is perfectly suitable for the JSON format.
20+
21+
---
22+
23+
### 1. 1D vector of scalars via JSON array
24+
25+
**Input**
26+
27+
~~~json
28+
["value1", "value2", ...]
29+
~~~
30+
31+
**Query**
32+
33+
~~~sql
34+
WITH
35+
folders AS (
36+
SELECT
37+
dirs."key" AS id,
38+
dirs.value AS path
39+
FROM
40+
json_each(
41+
'[' ||
42+
'"C:/Winows/System32/drivers/etc/hosts",' ||
43+
'"C:/Users/Public/Desktop/pic",' ||
44+
'"C:/Users/Default/Music/drum"' ||
45+
']'
46+
) AS dirs
47+
)
48+
SELECT * FROM folders;
49+
~~~
50+
51+
**Output**
52+
53+
| id | path |
54+
|----|--------------------------------------|
55+
| 0 | C:/Winows/System32/drivers/etc/hosts |
56+
| 1 | C:/Users/Public/Desktop/pic |
57+
| 2 | C:/Users/Default/Music/drum |
58+
59+
**Parameterized query**
60+
61+
~~~sql
62+
WITH
63+
folders AS (
64+
SELECT dirs."key" AS id, dirs.value AS path
65+
FROM json_each(@Paths) AS dirs
66+
)
67+
SELECT * FROM folders;
68+
~~~
69+
70+
---
71+
72+
### 2. 1D vector of pairs via JSON object
73+
74+
**Input**
75+
76+
~~~json
77+
{"pair1-value1": "pair1-value2", "pair2-value1": "pair2-value2", ...}
78+
~~~
79+
80+
**Query**
81+
82+
~~~sql
83+
WITH
84+
folders AS (
85+
SELECT
86+
dirs."key" AS bin_id,
87+
dirs.value AS path
88+
FROM
89+
json_each(
90+
'{' ||
91+
'"239": "C:/Winows/System32/drivers/etc/hosts",' ||
92+
'"876": "C:/Users/Public/Desktop/pic",' ||
93+
'"374": "C:/Users/Default/Music/drum"' ||
94+
'}'
95+
) AS dirs
96+
)
97+
SELECT * FROM folders;
98+
~~~
99+
100+
**Output**
101+
102+
| bin_id | path |
103+
|--------|--------------------------------------|
104+
| 239 | C:/Winows/System32/drivers/etc/hosts |
105+
| 876 | C:/Users/Public/Desktop/pic |
106+
| 374 | C:/Users/Default/Music/drum |
107+
108+
**Parameterized query**
109+
110+
~~~sql
111+
WITH
112+
folders AS (
113+
SELECT dirs."key" AS bin_id, dirs.value AS path
114+
FROM json_each(@Paths) AS dirs
115+
)
116+
SELECT * FROM folders;
117+
~~~
118+
119+
---
120+
121+
### 2. 1D vector of multicolumn row values via JSON array of objects
122+
123+
124+
**Input**
125+
126+
~~~json
127+
[
128+
{"attr1": "value1_1", "attr2": "value1_2", "attr3": "value1_3"},
129+
{"attr1": "value2_1", "attr2": "value2_2", "attr3": "value2_3"},
130+
...
131+
]
132+
~~~
133+
134+
**Query**
135+
136+
~~~sql
137+
WITH
138+
folders AS (
139+
SELECT
140+
json_extract(dirs.value, '$.bin_id') AS bin_id,
141+
json_extract(dirs.value, '$.prefix') AS prefix,
142+
json_extract(dirs.value, '$.name') AS name
143+
FROM
144+
json_each(
145+
'[' ||
146+
'{"bin_id": "239", "prefix": "C:/Winows/System32/drivers/etc", "name": "hosts"},' ||
147+
'{"bin_id": "876", "prefix": "C:/Users/Public/Desktop", "name": "pic" },' ||
148+
'{"bin_id": "374", "prefix": "C:/Users/Default/Music", "name": "drum" }' ||
149+
']'
150+
) AS dirs
151+
)
152+
SELECT * FROM folders;
153+
~~~
154+
155+
**Output**
156+
157+
| bin_id | prefix | name |
158+
|--------|--------------------------------|-------|
159+
| 239 | C:/Winows/System32/drivers/etc | hosts |
160+
| 876 | C:/Users/Public/Desktop | pic |
161+
| 374 | C:/Users/Default/Music | drum |
162+
163+
**Parameterized query**
164+
165+
~~~sql
166+
WITH
167+
folders AS (
168+
SELECT
169+
json_extract(dirs.value, '$.bin_id') AS bin_id,
170+
json_extract(dirs.value, '$.prefix') AS prefix,
171+
json_extract(dirs.value, '$.name') AS name
172+
FROM json_each(@Paths) AS dirs
173+
)
174+
SELECT * FROM folders;
175+
~~~
176+
177+
---

0 commit comments

Comments
 (0)