Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Fix typos, improve wording, and add more examples to the json1 documentation. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
51f0e6c4483baade090980b6ddd1913a |
User & Date: | drh 2015-09-11 15:23:29.580 |
Context
2015-09-11
| ||
15:36 | Still more typo corrections and clarification for the json1 documentation. (check-in: 854fe12156 user: drh tags: trunk) | |
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) | |
Changes
Changes to pages/json1.in.
︙ | ︙ | |||
44 45 46 47 48 49 50 | 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)} { | | | 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 | 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)} { Validate and minify 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)} { |
︙ | ︙ | |||
159 160 161 162 163 164 165 | 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. | | < | 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 | 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 parses JSON text at over 300 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. |
︙ | ︙ | |||
183 184 185 186 187 188 189 | <p> For functions that accept JSON as their first argument, that argument can be a JSON object, array, number, string, or null. SQLite numeric values and NULL values are interpreted as JSON numbers and nulls, respectively. SQLite text values can be understood as JSON objects, arrays, or strings. If an SQLite text value that is not a well-formed JSON object, array, or string is passed into json1 function, that function will usually throw | | | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | | | > > > > > > | | | 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 | <p> For functions that accept JSON as their first argument, that argument can be a JSON object, array, number, string, or null. SQLite numeric values and NULL values are interpreted as JSON numbers and nulls, respectively. SQLite text values can be understood as JSON objects, arrays, or strings. If an SQLite text value that is not a well-formed JSON object, array, or string is passed into json1 function, that function will usually throw an error. (An exception is the json_valid(X) function which returns 1 if X is well-formed JSON 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 VALUE arguments</h3> <p> For functions that accept "<i>value</i>" arguments (also shown as "<i>value1</i>" and "<i>value2</i>") that are used to construct or modify a JSON string, those arguments is usually understood to be a literal strings and are quoted to become primitive JSON string values in the result. Even if the input <i>value</i> strings looks like well-formed JSON, they are still interpreted as literal strings in the result. <p> However, if a <i>value</i> argument come from the output of another json function, then the argument is understood to be actual JSON and the complete JSON is inserted rather than a quoted string. <p> For example, in the following call to json_object(), the first <i>value</i> argument looks like a well-formed JSON array. But because it is just an ordinary SQL text value it is interpreted as a literal string and added to the result as a quoted string: <tcl> jexample {json_object('ex','[52,3.14159]')} {'{"ex":"[52,3.14159]"}'} </tcl> <p> But if the <i>value</i> argument in the outer json_object() call is the result of another json function like [json()] or [json_array()], then the value is understood to be actual JSON and is inserted as such: <tcl> jexample \ {json_object('ex',json('[52,3.14159]'))} {'{"ex":[52,3.14159]}'} \ {json_object('ex',json_array(52,3.14159))} {'{"ex":[52,3.14159]}'} </tcl> <h3>2.4 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 work in 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>If the argument X to json(X) contains JSON objects with duplicate labels, then it is undefined whether or not the duplicates are preserved. The current implementation preserves duplicates. However, future enhancements to this routine may choose to silently remove duplicates. <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 with SQL type TEXT it is normally converted into a quoted JSON string. However, if the argument is the output from 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> |
︙ | ︙ | |||
265 266 267 268 269 270 271 | <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 | | > | > > | > | | | | | > | | | 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 | <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 locates a element or X other than an JSON array, and NULL if path P does not locate any element of 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('[1,2,3,4]', '$')} {4} \ {json_array_length('[1,2,3,4]', '$[2]')} {0} \ {json_array_length('{"one":[1,2,3]}')} {0} \ {json_array_length('{"one":[1,2,3]}', '$.one')} {3} \ {json_array_length('{"one":[1,2,3]}', '$.two')} {NULL} </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 SQL datatype of the result is NULL for a JSON null, INTEGER or REAL for a JSON numeric value, an INTEGER zero for a JSON false value, an INTEGER one for a JSON true value, the dequoted text for a JSON string value, and a text representation for JSON object and array values. If there are multiple path arguments (P1, P2, and so forth) then this routine returns SQLite text which is a well-formed JSON array holding the various values. <p>Examples: <tcl> jexample \ {json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$')} \ {'{"a":2,"c":[4,5,{"f":7}]}'} \ {json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.c')} \ {'[4,5,{"f":7}]'} \ {json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.c[2]')} \ {'{"f":7}'} \ {json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.c[2].f')} {7} \ {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 \ {json_extract('{"a":2,"c":[4,5,{"f":7}]}', '$.x', '$.a')} {'[null,2]'} </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 string formed by updating the input JSON by the path/value pairs. The functions differ only in how they deal with creating new values and overwriting preexisting values. <center> <table border=1 cellpadding=3> <tr> <th>Function<th>Overwrite if already exists?<th>Create if does not exist? |
︙ | ︙ | |||
343 344 345 346 347 348 349 | 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 | | | > | | 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 | 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 value is the result of another json1 function (such as [json()] or [json_array()] or [json_object()]) then it is interpreted as JSON and is inserted as JSON retaining all of its substructure. <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 a 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}'} \ |
︙ | ︙ | |||
381 382 383 384 385 386 387 | 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. | | > | > | | | | | 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 | 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 with SQL type TEXT it is normally converted into a quoted JSON string even if the input text is well-formed JSON. However, if the argument is the direct result from another json1 function, then it is treated as JSON and all of its JSON type information and substructure is preserved. 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. The json_remove(X,P,...) function returns a new JSON value that is the X with all the elements identified by path arguments removed. Paths that select elements not found in X are silently ignored. <p>Removals occurs sequentially from left to right. Changes caused by prior removals can affect the path search for subsequent arguments. <p>If the json_remove(X) function is called with no path arguments, |
︙ | ︙ | |||
437 438 439 440 441 442 443 | <tcl>hd_fragment jtype {json_type SQL function} {json_type}</tcl> <h3>3.7 The json_type() function</h3> <p>The json_type(X) function returns the "type" of the outermost element of X. The json_type(X,P) function returns the "type" of the element in X that is selected by path P. The "type" returned by json_type() is | | | | | 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 | <tcl>hd_fragment jtype {json_type SQL function} {json_type}</tcl> <h3>3.7 The json_type() function</h3> <p>The json_type(X) function returns the "type" of the outermost element of X. The json_type(X,P) function returns the "type" of the element in X that is selected by path P. The "type" returned by json_type() is on of the following an SQL text values: 'null', 'true', 'false', 'integer', 'real', 'text', 'array', or 'object'. If the path P in json_type(X,P) selects a element that does not exist in X, then this function returns NULL. <p>The json_type() function throws an error if any of its arguments are not well-formed or is a BLOB. <p>Examples: <tcl> jexample \ {json_type('{"a":[2,3.5,true,false,null,"x"]}')} 'object' \ {json_type('{"a":[2,3.5,true,false,null,"x"]}','$')} 'object' \ |
︙ | ︙ | |||
567 568 569 570 571 572 573 | SELECT DISTINCT user.name FROM user, json_each(user.phone) WHERE json_each.value LIKE '704-%'; </pre></blockquote> <p>Now suppose the user.phone field contains plain text if the user has only a single phone number and a JSON array if the user has multiple | | | | 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 | SELECT DISTINCT user.name FROM user, json_each(user.phone) WHERE json_each.value LIKE '704-%'; </pre></blockquote> <p>Now suppose the user.phone field contains plain text if the user has only a single phone number and a JSON array if the user has multiple phone numbers. The same question is posed: "Which users have a phone number in the 704 area code?" But now the json_each() function can only be called for those users that have two or more phone numbers since json_each() requires well-formed JSON as its first argument: <blockquote><pre> SELECT name FROM user WHERE phone LIKE '704-%' UNION SELECT user.name FROM user, json_each(user.phone) |
︙ | ︙ | |||
600 601 602 603 604 605 606 | <blockquote><pre> SELECT big.rowid, fullkey, atom FROM big, json_tree(big.json) WHERE atom IS NOT NULL; </pre></blockquote> | | | | | 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 | <blockquote><pre> SELECT big.rowid, fullkey, atom FROM big, json_tree(big.json) WHERE atom IS NOT NULL; </pre></blockquote> <p>Suppose each entry in the BIG table is a JSON object with a '$.id' field that is a unique indentifier and a '$.partlist' field that can be a deeply nested object. You want to find the id of every entry that contains one or more references to uuid '6fa5181e-5721-11e5-a04e-57f3d7b32808' anywhere in its '$.partlist'. <blockquote><pre> SELECT DISTINCT json_extract(big.json,'$.id') FROM big, json_tree(big.json, '$.partlist') WHERE json_tree.key='uuid' AND json_tree.value='6fa5181e-5721-11e5-a04e-57f3d7b32808'; </pre></blockquote> |