Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Update the json1 documentation to reflect the recent changes that make use of subtype to avoid the '$$' goofiness, and the addition of the json() function. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
ad300537321c2c4bf63da985b45f23fb |
User & Date: | drh 2015-09-11 01:22:08.121 |
Context
2015-09-11
| ||
15:23 | Fix typos, improve wording, and add more examples to the json1 documentation. (check-in: 51f0e6c448 user: drh tags: trunk) | |
01:22 | Update the json1 documentation to reflect the recent changes that make use of subtype to avoid the '$$' goofiness, and the addition of the json() function. (check-in: ad30053732 user: drh tags: trunk) | |
2015-09-10
| ||
19:27 | Fix another typo in the json1 documentation. (check-in: 02e2ca3d77 user: drh tags: trunk) | |
Changes
Changes to pages/json1.in.
1 2 3 4 5 6 | <title>The JSON1 Extension</title> <tcl>hd_keywords json1 {the json1 extension}</tcl> <h2>The JSON1 Extension</h2> <p> The <b>json1</b> extension is a [loadable extension] that | | > | 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 | <title>The JSON1 Extension</title> <tcl>hd_keywords json1 {the json1 extension}</tcl> <h2>The JSON1 Extension</h2> <p> The <b>json1</b> extension is a [loadable extension] that implements eleven [application-defined SQL functions] and two [table-valued functions] that are useful for managing JSON content stored in an SQLite database. These are the SQL functions implemented by json1: <blockquote> <center><table border=0 cellpadding=5> <tcl> set tabcnt 0 proc tabentry {fx desc lnk} { global tabcnt incr tabcnt hd_puts "<tr><td width=30 valign='top'>$tabcnt.</td>" hd_puts "<td valign='top' width='30%'>\n" set fx [string trim $fx] set hlink "<a href='#$lnk'>" regsub -all {^json\(} $fx "${hlink}json</a>(" fx regsub -all {(json_[a-z_]+)} $fx "$hlink\\1</a>" fx regsub -all {(value[1-9]?|path|label[1-9]?)} $fx "<i>\\1</i>" fx regsub -all {\((json)} $fx "(<i>\\1</i>" fx hd_puts $fx\n hd_puts "</td><td valign='top'>\n" hd_puts [string trim $desc]\n hd_puts "</td></tr>\n\n" |
︙ | ︙ | |||
41 42 43 44 45 46 47 48 49 50 51 52 53 54 | # puts "\175 \173$x\175" hd_puts "<tr><td>[string trim $sql]</td>\n" hd_puts "<td width='50' align='center'><b>→</b></td>\n" hd_puts "<td>[string trim $res]</td></tr>\n" } hd_puts "</table></blockquote>\n" } tabentry {json_array(value1,value2,...)} { Return a JSON array holding the function arguments. } jarray tabentry {json_array_length(json)<br>json_array_length(json,path)} { Return the number of elements in the JSON array identified by | > > > > | 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 | # puts "\175 \173$x\175" hd_puts "<tr><td>[string trim $sql]</td>\n" hd_puts "<td width='50' align='center'><b>→</b></td>\n" hd_puts "<td>[string trim $res]</td></tr>\n" } hd_puts "</table></blockquote>\n" } tabentry {json(json)} { Validates and minifies a JSON string } jmini tabentry {json_array(value1,value2,...)} { Return a JSON array holding the function arguments. } jarray tabentry {json_array_length(json)<br>json_array_length(json,path)} { Return the number of elements in the JSON array identified by |
︙ | ︙ | |||
148 149 150 151 152 153 154 | <p> The json1 extension (currently) stores JSON as ordinary text. <p> Backwards compatibility constraints mean that SQLite is only able to store values that are NULL, integers, floating-point numbers, text, | | < < < < > > | | | 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 | <p> The json1 extension (currently) stores JSON as ordinary text. <p> Backwards compatibility constraints mean that SQLite is only able to store values that are NULL, integers, floating-point numbers, text, and BLOBs. It is not possible add a sixth "JSON" type. <p> The json1 extension does not (currently) support a binary encoding of JSON. Experiments have so far been unable to find a binary encoding that is significantly smaller or faster than a plain text encoding. (The present implementation is able to parse JSON text at a rate of 250 MB/s.) The current implementation of the various JSON functions always errors out if it see a BLOB argument, because BLOBs are reserved for a future enhancement in which BLOBs will store the binary encoding for JSON. <p> The "1" at the end of the name for the json1 extension is deliberate. The designers anticipate that there will be future incompatible JSON extensions building upon the lessons learned from json1. Once sufficient experience is gained, some kind of JSON extension might be folded into the SQLite core. But for now, |
︙ | ︙ | |||
186 187 188 189 190 191 192 | string is passed into json1 function, that function will usually throw an error. (The exception to the previous sentence is the json_valid() function which returns 1 if the argument is well-formed and 0 if it is not.) <p> For the purposes of determining validity, leading and trailing whitespace on JSON inputs is ignored. Interior whitespace is also ignored, in accordance | | | < < < < < < | | > > > > > > > > > > > > > > > > > > > > > > > > > | | < | > | | < > | > > | | | 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 | string is passed into json1 function, that function will usually throw an error. (The exception to the previous sentence is the json_valid() function which returns 1 if the argument is well-formed and 0 if it is not.) <p> For the purposes of determining validity, leading and trailing whitespace on JSON inputs is ignored. Interior whitespace is also ignored, in accordance with the JSON spec. These routines accept exactly the rfc-7159 JSON syntax — no more and no less. <h3>2.2 PATH arguments</h3> <p> For functions that accept PATH arguments, that PATH must be well-formed or else the function will throw an error. A well-formed PATH is a text value that begins with exactly one '$' character followed by zero or more instances of ".<i>objectlabel</i>" or "[<i>arrayindex</i>]". <h3>2.3 Compatibility</h3> <p> The json1 extension uses the [sqlite3_value_subtype()] and [sqlite3_result_subtype()] interfaces that were introduced with SQLite version 3.8.12. Therefore the json1 extension will not load into earlier versions of SQLite. <h2>3.0 Function Details</h2> <p>The following sections provide additional detail on the operation of the various functions that are part of the json1 extension. <tcl>hd_fragment jmini {json SQL function} {json}</tcl> <h3>3.1 The json() function</h3> <p>The json(X) function verifies that its argument X is a valid JSON string and returns a minified version of that JSON string (with all unnecessary whitespace removed). If X is not a well-formed JSON string, then this routine throws an error. <p> Example: <tcl> jexample \ {json(' { "this" : "is", "a": [ "test" ] } ')} \ {'{"this":"is","a":["test"]}'} </tcl> <tcl>hd_fragment jarray {json_array SQL function} {json_array}</tcl> <h3>3.2 The json_array() function</h3> <p>The json_array() SQL function accepts zero or more arguments and returns a well-formed JSON array that is composed from those arguments. If any argument to json_array() is a BLOB then an error is thrown. <p>An argument is of type TEXT it is normally converted into a quoted JSON string. However, if the argument is the outpu to another json1 function, then it is stored as JSON. This allows calls to json_array() and [json_object()] to be nested. The [json()] function can also be used to force strings to be recognized as JSON. <p>Examples: <tcl> jexample \ {json_array(1,2,'3',4)} {'[1,2,"3",4]'} \ {json_array('[1,2]')} {'["[1,2]"]'} \ {json_array(json_array(1,2))} {'[[1,2]]'} \ {json_array(1,null,'3','[4,5]','{"six":7.7}')} \ {'[1,null,"3","[4,5]","{\"six\":7.7}"]'} \ {json_array(1,null,'3',json('[4,5]'),json('{"six":7.7}'))} \ {'[1,null,"3",[4,5],{"six":7.7}]'} </tcl> <tcl>hd_fragment jarraylen {json_array_length SQL function} \ {json_array_length}</tcl> <h3>3.3 The json_array_length() function</h3> <p>The json_array_length(X) function returns the number of elements in the JSON array X, or 0 if X is some kind of JSON value other than an array. The json_array_length(X,P) locates the array at path P within X and returns the length of that array, or 0 if path P does not locate an array within X. Errors are thrown if either X is not well-formed JSON or if P is not a well-formed path. <p>Examples: <tcl> jexample \ {json_array_length('[1,2,3,4]')} {4} \ {json_array_length('{"one":[1,2,3]}')} {0} \ {json_array_length('{"one":[1,2,3]}', '$.one')} {3} </tcl> <tcl>hd_fragment jex {json_extract SQL function} {json_extract}</tcl> <h3>3.4 The json_extract() function</h3> <p>The json_extract(X,P1,P2,...) extracts and returns one or more values from the well-formed JSON at X. If only a single path P1 is provided, then the SQLite type of the value returned is NULL for a JSON null, INTEGER or REAL for a JSON numeric value, INTEGER 0 for a JSON false value, INTEGER 1 for a JSON true value, the dequoted text for a JSON string value, and |
︙ | ︙ | |||
287 288 289 290 291 292 293 | {json_extract('{"a":2,"c":[4,5],"f":7}','$.c','$.a')} {'[[4,5],2]'} \ {json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.x')} NULL </tcl> <tcl>hd_fragment jins {json_insert SQL function} {json_insert}</tcl> <tcl>hd_fragment jrepl {json_replace SQL function} {json_replace}</tcl> <tcl>hd_fragment jset {json_set SQL function} {json_set}</tcl> | | | 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 | {json_extract('{"a":2,"c":[4,5],"f":7}','$.c','$.a')} {'[[4,5],2]'} \ {json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.x')} NULL </tcl> <tcl>hd_fragment jins {json_insert SQL function} {json_insert}</tcl> <tcl>hd_fragment jrepl {json_replace SQL function} {json_replace}</tcl> <tcl>hd_fragment jset {json_set SQL function} {json_set}</tcl> <h3>3.5 The json_insert(), json_replace, and json_set() functions</h3> <p>The json_insert(), json_replace, and json_set() functions all take a single JSON value as their first argument followed by zero or more pairs of path and value arguments, and return a new JSON value formed by updating the input argument by the path/value pairs. The functions differ only in how they deal with creating new values and overwriting preexisting values. |
︙ | ︙ | |||
317 318 319 320 321 322 323 | JSON to be edited. Subsequent arguments occur in pairs with the first element of each pair being a path and the second element being an value to insert or replace or set on that path. <p>Edits occurs sequentially from left to right. Changes caused by prior edits can affect the path search for subsequent edits. | < < | | < < | < < > | < | > > > > > > | | < | > | | < | > | | 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 | JSON to be edited. Subsequent arguments occur in pairs with the first element of each pair being a path and the second element being an value to insert or replace or set on that path. <p>Edits occurs sequentially from left to right. Changes caused by prior edits can affect the path search for subsequent edits. <p>If the value of a path/value pair is an SQLite TEXT value, then it is normally inserted as a quoted JSON string, even if the string looks like valid JSON. However, if the TEXT value is the output of another json1 function (such as [json()] or [json_array()] or [json_object()]) then it is interpreted as JSON and is inserted as is. <p>These routines throw an error if the first JSON argument is not well-formed or if any PATH argument is not well-formed or if any argument is of type BLOB. <p>Examples: <tcl> jexample \ {json_insert('{"a":2,"c":4}', '$.a', 99)} {'{"a":2,"c":4}'} \ {json_insert('{"a":2,"c":4}', '$.e', 99)} {'{"a":2,"c":4,"e":99}'} \ {json_replace('{"a":2,"c":4}', '$.a', 99)} {'{"a":99,"c":4}'} \ {json_replace('{"a":2,"c":4}', '$.e', 99)} {'{"a":2,"c":4}'} \ {json_set('{"a":2,"c":4}', '$.a', 99)} {'{"a":99,"c":4}'} \ {json_set('{"a":2,"c":4}', '$.e', 99)} {'{"a":2,"c":4,"e":99}'} \ {json_set('{"a":2,"c":4}', '$.c', '[97,96]')} \ {'{"a":2,"c":"[97,96]"}'} \ {json_set('{"a":2,"c":4}', '$.c', json('[97,96]'))} \ {'{"a":2,"c":[97,96]}'} \ {json_set('{"a":2,"c":4}', '$.c', json_array(97,96))} \ {'{"a":2,"c":[97,96]}'} </tcl> <tcl>hd_fragment jobj {json_object SQL function} {json_object}</tcl> <h3>3.6 The json_object() function</h3> <p>The json_object() SQL function accepts zero or more pairs of arguments and returns a well-formed JSON object that is composed from those arguments. The first argument of each pair is the label and the second argument of each pair is the value. If any argument to json_object() is a BLOB then an error is thrown. <p>The json_object() function currently allows duplicate labels without complaint, though this might change in a future enhancement. <p>An argument is of type TEXT it is normally converted into a quoted JSON string. However, if the argument is the output to another json1 function, then it is stored as JSON. This allows calls to json_object() and [json_array()] to be nested. The [json()] function can also be used to force strings to be recognized as JSON. <p>Examples: <tcl> jexample \ {json_object('a',2,'c',4)} {'{"a":2,"c":4}'} \ {json_object('a',2,'c','{e:5}')} {'{"a":2,"c":"{e:5}"}'} \ {json_object('a',2,'c',json_object('e',5))} {'{"a":2,"c":{"e":5}}'} </tcl> <tcl>hd_fragment jrm {json_remove SQL function} {json_remove}</tcl> <h3>3.7 The json_remove() function</h3> <p>The json_remove(X,P,...) function takes a single JSON value as its first argument followed by zero or more path arguments in the second and subsequent arguments. The json_remove(X,P,...) function returns a new JSON value that is the input X value with all the elements identified by path arguments removed. Paths that select elements not found in X are silently ignored. |
︙ | ︙ | |||
438 439 440 441 442 443 444 | {json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[3]')} 'false' \ {json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[4]')} 'null' \ {json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[5]')} 'text' \ {json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[6]')} NULL </tcl> <tcl>hd_fragment jvalid {json_valid SQL function} {json_valid}</tcl> | | | 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 | {json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[3]')} 'false' \ {json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[4]')} 'null' \ {json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[5]')} 'text' \ {json_type('{"a":[2,3.5,true,false,null,"x"]}','$.a[6]')} NULL </tcl> <tcl>hd_fragment jvalid {json_valid SQL function} {json_valid}</tcl> <h3>3.9 The json_valid() function</h3> <p>The json_valid(X) function return 1 if the argument X is well-formed JSON and return 0 if the argument X is not well-formed JSON. <p>Examples: <tcl> |
︙ | ︙ | |||
529 530 531 532 533 534 535 | <p> The "path" column is the path to the array or object container the holds the current row, or the path to the current row in the case where the iteration starts on a primitive type and thus only provides a single row of output. | | | 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 | <p> The "path" column is the path to the array or object container the holds the current row, or the path to the current row in the case where the iteration starts on a primitive type and thus only provides a single row of output. <h4>3.10.1 Examples using json_each() and json_tree()</h4> <p>Suppose the table "CREATE TABLE user(name,phone)" stores zero or more phone numbers as a JSON array object in the user.phone field. To find all users who have any phone number with a 704 area code: <blockquote><pre> SELECT DISTINCT user.name |
︙ | ︙ |