|
| 1 | +--- |
| 2 | +layout: default |
| 3 | +title: JSON and DSV Output |
| 4 | +nav_order: 5 |
| 5 | +parent: Design Patterns |
| 6 | +permalink: /patterns/json-sql-output |
| 7 | +--- |
| 8 | + |
| 9 | +Using JSON, rather than a record set, for encoding the returned data may also be more efficient due to the reduced number of required API calls. While SQLite API is usually fast, each returned value still costs several API calls. (Under certain circumstances, however, there might be a high SQLite-independent overhead for each API call.) Another important consideration is whether there are any potential side effects of data conversion between numeric and textual formats. Let us show a few examples. |
| 10 | + |
| 11 | +Consider a modified query from the [Surrogate Variables](/patterns/variables#DSV-Query) section: |
| 12 | + |
| 13 | +~~~sql |
| 14 | +WITH |
| 15 | + delimiters(delimiter) AS (VALUES ('/')), |
| 16 | + strings(string_id, string) AS ( |
| 17 | + VALUES |
| 18 | + ('abc', 'C:/Winows/System32/drivers/etc/'), |
| 19 | + ('def', 'C:/Users/Public/Desktop') |
| 20 | + ), |
| 21 | + folders AS ( |
| 22 | + SELECT string_id, "terms"."key" AS term_id, "terms"."value" AS term |
| 23 | + FROM |
| 24 | + delimiters, strings, |
| 25 | + json_each('["' || replace(trim(string, delimiter), delimiter, '", "') || '"]') AS terms |
| 26 | + ORDER BY string_id, term_id |
| 27 | + ), |
| 28 | + json_folders AS ( |
| 29 | + SELECT string_id, json_group_array(term) AS path_json |
| 30 | + FROM folders |
| 31 | + GROUP BY string_id |
| 32 | + ) |
| 33 | +SELECT * FROM json_folders; |
| 34 | +~~~ |
| 35 | + |
| 36 | +which outputs: |
| 37 | + |
| 38 | +| string_id | path_json | |
| 39 | +|-----------|--------------------------------------------| |
| 40 | +| abc | ["C:","Winows","System32","drivers","etc"] | |
| 41 | +| def | ["C:","Users","Public","Desktop"] | |
| 42 | + |
| 43 | +This query has a new section, *json_folders*, at the end, which uses *json_group_array* to collect folders belonging to the same path. Note that the ordering clause is added to the *folders* section to ensure that the order of individual folders within JSON arrays after grouping reflects their positions in original paths. |
| 44 | + |
| 45 | +--- |
| 46 | + |
| 47 | +Similarly, the following modified query: |
| 48 | + |
| 49 | +~~~sql |
| 50 | +WITH |
| 51 | + folders AS ( |
| 52 | + SELECT |
| 53 | + json_extract(dirs.value, '$.bin_id') AS bin_id, |
| 54 | + json_extract(dirs.value, '$.prefix') AS prefix, |
| 55 | + json_extract(dirs.value, '$.name') AS name |
| 56 | + FROM |
| 57 | + json_each( |
| 58 | + '[' || |
| 59 | + '{"bin_id": "239", "prefix": "C:/Winows/System32/drivers/etc", "name": "hosts"},' || |
| 60 | + '{"bin_id": "876", "prefix": "C:/Users/Public/Desktop", "name": "pic" },' || |
| 61 | + '{"bin_id": "374", "prefix": "C:/Users/Default/Music", "name": "drum" }' || |
| 62 | + ']' |
| 63 | + ) AS dirs |
| 64 | + ), |
| 65 | + json_fs_objects AS ( |
| 66 | + SELECT |
| 67 | + json_group_array(json_object('bin_id', bin_id, 'prefix', prefix, 'name', name)) AS fs_objects |
| 68 | + FROM folders |
| 69 | + ) |
| 70 | +SELECT * FROM json_fs_objects; |
| 71 | +~~~ |
| 72 | + |
| 73 | +return a scalar string containing a set of records in the JSON format: |
| 74 | + |
| 75 | +~~~sql |
| 76 | +[ |
| 77 | + {"bin_id": "239", "name": "hosts", "prefix": "C:/Winows/System32/drivers/etc"}, |
| 78 | + {"bin_id": "876", "name": "pic", "prefix": "C:/Users/Public/Desktop" }, |
| 79 | + {"bin_id": "374", "name": "drum", "prefix": "C:/Users/Default/Music" } |
| 80 | +] |
| 81 | +~~~ |
| 82 | + |
| 83 | +JSON objects are a bit too verbous when returning a record set, but there are a few other options. For example: |
| 84 | + |
| 85 | +~~~sql |
| 86 | +WITH |
| 87 | + folders AS ( |
| 88 | + SELECT |
| 89 | + json_extract(dirs.value, '$.bin_id') AS bin_id, |
| 90 | + json_extract(dirs.value, '$.prefix') AS prefix, |
| 91 | + json_extract(dirs.value, '$.name') AS name |
| 92 | + FROM |
| 93 | + json_each( |
| 94 | + '[' || |
| 95 | + '{"bin_id": "239", "prefix": "C:/Winows/System32/drivers/etc", "name": "hosts"},' || |
| 96 | + '{"bin_id": "876", "prefix": "C:/Users/Public/Desktop", "name": "pic" },' || |
| 97 | + '{"bin_id": "374", "prefix": "C:/Users/Default/Music", "name": "drum" }' || |
| 98 | + ']' |
| 99 | + ) AS dirs |
| 100 | + ), |
| 101 | + tsv_fs_objects AS ( |
| 102 | + SELECT group_concat(bin_id || x'09' || prefix || x'09' || name, x'0A') AS fs_objects |
| 103 | + FROM folders |
| 104 | + ) |
| 105 | +SELECT * FROM tsv_fs_objects; |
| 106 | +~~~ |
| 107 | + |
| 108 | +or |
| 109 | + |
| 110 | +~~~sql |
| 111 | +WITH |
| 112 | + folders AS ( |
| 113 | + SELECT |
| 114 | + json_extract(dirs.value, '$.bin_id') AS bin_id, |
| 115 | + json_extract(dirs.value, '$.prefix') AS prefix, |
| 116 | + json_extract(dirs.value, '$.name') AS name |
| 117 | + FROM |
| 118 | + json_each( |
| 119 | + '[' || |
| 120 | + '{"bin_id": "239", "prefix": "C:/Winows/System32/drivers/etc", "name": "hosts"},' || |
| 121 | + '{"bin_id": "876", "prefix": "C:/Users/Public/Desktop", "name": "pic" },' || |
| 122 | + '{"bin_id": "374", "prefix": "C:/Users/Default/Music", "name": "drum" }' || |
| 123 | + ']' |
| 124 | + ) AS dirs |
| 125 | + ), |
| 126 | + tsv_fs_objects AS ( |
| 127 | + SELECT |
| 128 | + group_concat(printf('%s' || x'09' || '%s' || x'09' || '%s', bin_id, prefix, name), x'0A') AS fs_objects |
| 129 | + FROM folders |
| 130 | + ) |
| 131 | +SELECT * FROM tsv_fs_objects; |
| 132 | +~~~ |
| 133 | + |
| 134 | +or |
| 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 | + records AS ( |
| 153 | + SELECT |
| 154 | + 'bin_id' || x'09' || 'prefix' || x'09' || 'name' || x'0A' || |
| 155 | + 'str' || x'09' || 'str' || x'09' || 'str' AS record |
| 156 | + UNION ALL |
| 157 | + SELECT bin_id || x'09' || prefix || x'09' || name AS record |
| 158 | + FROM folders |
| 159 | + ), |
| 160 | + tsv_fs_objects AS ( |
| 161 | + SELECT group_concat(record, x'0A') AS fs_objects |
| 162 | + FROM records |
| 163 | + ) |
| 164 | +SELECT * FROM tsv_fs_objects; |
| 165 | +~~~ |
| 166 | + |
| 167 | +return a scalar string containing a set of records in the tab-separated value format. The last query also adds a table header. |
0 commit comments