Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Add documentation for the json_quote() SQL function. Updates to the change log. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
3506feb7c767b24941f72a4c7e983720 |
User & Date: | drh 2016-07-23 19:42:54.505 |
Context
2016-07-23
| ||
21:45 | Tweaks to the JSON extension docs. (check-in: d0a0b0987f user: drh tags: trunk) | |
19:42 | Add documentation for the json_quote() SQL function. Updates to the change log. (check-in: 3506feb7c7 user: drh tags: trunk) | |
14:58 | Mention the sqlite3_expanded_sql() and sqlite3_trace_v2() interfaces in the change log. (check-in: eecfde6ba8 user: drh tags: trunk) | |
Changes
Changes to pages/changes.in.
︙ | ︙ | |||
17 18 19 20 21 22 23 | proc chng {date desc {options {}}} { global nChng aChng xrefChng set aChng($nChng) [list $date $desc $options] set xrefChng($date) $nChng incr nChng } | | | 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 | proc chng {date desc {options {}}} { global nChng aChng xrefChng set aChng($nChng) [list $date $desc $options] set xrefChng($date) $nChng incr nChng } chng {2016-08-00 (3.14.0)} { <li>Added support for [WITHOUT ROWID virtual tables]. <li>Improved the query planner so that the [OR optimization] can be used on [virtual tables] even if one or more of the disjuncts use the [LIKE], [GLOB], [REGEXP], [MATCH] operators. <li>Added the [CSV virtual table] for reading [https://www.ietf.org/rfc/rfc4180.txt|RFC 4180] formatted comma-separated value files. |
︙ | ︙ | |||
49 50 51 52 53 54 55 | <li>Added the "win32-none" VFS, analogous to the "unix-none" VFS, that works like the default "win32" VFS except that it ignores all file locks. <li>The query planner uses a full scan of a [partial index] instead of a full scan of the main table, in cases where that makes sense. <li>Allow [table-valued functions] to appear on the right-hand side of an [IN operator]. <li>Created the [dbhash.exe] command-line utility. <li>Added two new C-language interfaces: [sqlite3_expanded_sql()] and | | > > > > > > > > | 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 | <li>Added the "win32-none" VFS, analogous to the "unix-none" VFS, that works like the default "win32" VFS except that it ignores all file locks. <li>The query planner uses a full scan of a [partial index] instead of a full scan of the main table, in cases where that makes sense. <li>Allow [table-valued functions] to appear on the right-hand side of an [IN operator]. <li>Created the [dbhash.exe] command-line utility. <li>Added two new C-language interfaces: [sqlite3_expanded_sql()] and [sqlite3_trace_v2()]. <li>Added the [json_quote()] SQL functio to [the json1 extension]. <p><b>Bug Fixes:</b> <li>Fix the [ALTER TABLE] command so that it does not corrupt [descending indexes] when adding a column to a [legacy_file_format|legacy file format] database. Ticket [https://www.sqlite.org/src/info/f68bf68513a1c15f|f68bf68513a1c15f] <li>Fix a NULL-pointer dereference/crash that could occurs when a transitive WHERE clause references a non-existent collating sequence. Ticket [https://www.sqlite.org/src/info/e8d439c77685eca6|e8d439c77685eca6]. } chng {2016-05-18 (3.13.0)} { <li>Postpone I/O associated with TEMP files for as long as possible, with the hope that the I/O can ultimately be avoided completely. <li>Merged the [session] extension into trunk. <li>Added the ".auth ON|OFF" command to the [command-line shell]. |
︙ | ︙ |
Changes to pages/json1.in.
1 2 | <title>The JSON1 Extension</title> <tcl>hd_keywords json1 {the json1 extension} {JSON SQL functions}</tcl> | | > > | 1 2 3 4 5 6 7 8 9 10 11 12 13 | <title>The JSON1 Extension</title> <tcl>hd_keywords json1 {the json1 extension} {JSON SQL functions}</tcl> <table_of_contents> <h1>Overview</h1> <p> The <b>json1</b> extension is a [loadable extension] that implements thirteen [application-defined SQL functions] and two [table-valued functions] that are useful for managing [http://json.org/ | JSON] content stored in an SQLite database. These are the scalar SQL functions implemented by json1: |
︙ | ︙ | |||
89 90 91 92 93 94 95 96 97 98 99 100 101 102 | tabentry {json_type(json)<br>json_type(json,path)} { Return the type of a JSON string or subcomponent. } jtype tabentry {json_valid(json)} { Return true (1) if the input text is a valid JSON string } jvalid </tcl> </table></center></blockquote> <p>There are two aggregate SQL functions: <blockquote><center><table border=0 cellpadding=5> <tcl> | > > > > > | 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 | tabentry {json_type(json)<br>json_type(json,path)} { Return the type of a JSON string or subcomponent. } jtype tabentry {json_valid(json)} { Return true (1) if the input text is a valid JSON string } jvalid tabentry {json_quote(value)} { Convert an SQL value (a number or a string) into its corresponding JSON representation. } jvalid </tcl> </table></center></blockquote> <p>There are two aggregate SQL functions: <blockquote><center><table border=0 cellpadding=5> <tcl> |
︙ | ︙ | |||
125 126 127 128 129 130 131 | Walk the JSON recursively starting at the top-level or at the specified "path" and return one row for each element. } jtree </tcl> </table></center></blockquote> <tcl>hd_fragment howtocompile</tcl> | | | | 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 | Walk the JSON recursively starting at the top-level or at the specified "path" and return one row for each element. } jtree </tcl> </table></center></blockquote> <tcl>hd_fragment howtocompile</tcl> <h1>Compiling the JSON1 Extension</h1> <p> The [loadable extensions] documentation contains instructions on how to [compile loadable extensions] as shared libraries. The techniques described there work fine for the json1 module. <p> The json1 source code is included with the SQLite [amalgamation], though it is turned off by default. Add the [-DSQLITE_ENABLE_JSON1] compile-time option to enable the json1 extension that is built into the [amalgamation]. <h1>Interface Overview</h1> <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, |
︙ | ︙ | |||
165 166 167 168 169 170 171 | 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. For now, JSON support remains an extension. | | | | | 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 | 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. For now, JSON support remains an extension. <h2>JSON arguments</h2> <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 [http://www.rfc-editor.org/rfc/rfc7159.txt | rfc-7159 JSON syntax] — no more and no less. <h2>PATH arguments</h2> <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>]". <h2>VALUE arguments</h2> <p> For functions that accept "<i>value</i>" arguments (also shown as "<i>value1</i>" and "<i>value2</i>"), those arguments is usually understood to be a literal strings that are quoted and becomes JSON string values in the result. Even if the input <i>value</i> strings look like |
︙ | ︙ | |||
236 237 238 239 240 241 242 | <p> To be clear: "<i>json</i>" arguments are always interpreted as JSON regardless of where the value for that argument comes from. But "<i>value</i>" arguments are only interpreted as JSON if those arguments come directly from another json1 function. | | | | | 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 | <p> To be clear: "<i>json</i>" arguments are always interpreted as JSON regardless of where the value for that argument comes from. But "<i>value</i>" arguments are only interpreted as JSON if those arguments come directly from another json1 function. <h2>Compatibility</h2> <p> The json1 extension uses the [sqlite3_value_subtype()] and [sqlite3_result_subtype()] interfaces that were introduced with SQLite version 3.9.0. Therefore the json1 extension will not work in earlier versions of SQLite. <h1>Function Details</h1> <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> <h2>The json() function</h2> <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 |
︙ | ︙ | |||
273 274 275 276 277 278 279 | <tcl> jexample \ {json(' { "this" : "is", "a": [ "test" ] } ')} \ {'{"this":"is","a":["test"]}'} </tcl> <tcl>hd_fragment jarray {json_array SQL function} {json_array}</tcl> | | | 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 | <tcl> jexample \ {json(' { "this" : "is", "a": [ "test" ] } ')} \ {'{"this":"is","a":["test"]}'} </tcl> <tcl>hd_fragment jarray {json_array SQL function} {json_array}</tcl> <h2>The json_array() function</h2> <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 |
︙ | ︙ | |||
301 302 303 304 305 306 307 | {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> | | | 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 | {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> <h2>The json_array_length() function</h2> <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 a JSON array, and NULL if path P does not locate any element of X. Errors are thrown if either X is not |
︙ | ︙ | |||
325 326 327 328 329 330 331 | {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> | | | 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 | {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> <h2>The json_extract() function</h2> <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 |
︙ | ︙ | |||
357 358 359 360 361 362 363 | {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> | | | 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 | {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> <h2>The json_insert(), json_replace, and json_set() functions</h2> <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. |
︙ | ︙ | |||
417 418 419 420 421 422 423 | {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> | | | 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 | {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> <h2>The json_object() function</h2> <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. |
︙ | ︙ | |||
447 448 449 450 451 452 453 | {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> | | | 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 | {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> <h2>The json_remove() function</h2> <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. |
︙ | ︙ | |||
481 482 483 484 485 486 487 | {json_remove('{"x":25,"y":42}')} {'{"x":25,"y":42}'} \ {json_remove('{"x":25,"y":42}','$.z')} {'{"x":25,"y":42}'} \ {json_remove('{"x":25,"y":42}','$.y')} {'{"x":25}'} \ {json_remove('{"x":25,"y":42}','$')} NULL </tcl> <tcl>hd_fragment jtype {json_type SQL function} {json_type}</tcl> | | | 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 | {json_remove('{"x":25,"y":42}')} {'{"x":25,"y":42}'} \ {json_remove('{"x":25,"y":42}','$.z')} {'{"x":25,"y":42}'} \ {json_remove('{"x":25,"y":42}','$.y')} {'{"x":25}'} \ {json_remove('{"x":25,"y":42}','$')} NULL </tcl> <tcl>hd_fragment jtype {json_type SQL function} {json_type}</tcl> <h2>The json_type() function</h2> <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 |
︙ | ︙ | |||
511 512 513 514 515 516 517 | {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> | | > > > > > > > > > > > > > > | | | | 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 | {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> <h2>The json_valid() function</h2> <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> jexample \ {json_valid('{"x":35}')} 1 \ "json_valid('\173\"x\":35')" 0 </tcl> <tcl>hd_fragment jquote {json_quote SQL function} {json_quote}</tcl> <h2>The json_quote() function</h2> <p>The json_quote(X) function converts the SQL value X (a number or a string) into its corresponding JSON representation. <p>Examples: <tcl> jexample \ {json_quote(3.14159)} 3.14159 \ "json_quote('verdant')" \"verdant\" </tcl> <tcl> hd_fragment jgrouparray {json_group_array SQL function} \ {json_group_array} hd_fragment jgroupobject {json_group_object SQL function} \ {json_group_object} </tcl> <h2>The json_group_array() and json_group_object() aggregate SQL functions</h2> <p>The json_group_array(X) function is an [Aggregate Functions|aggregate SQL function] that returns a JSON array comprised of all X values in the aggregation. Similarly, the json_group_object(NAME,VALUE) function returns a JSON object comprised of all NAME/VALUE pairs in the aggregation. <tcl>hd_fragment jeach {json_each table-valued function} {json_each}</tcl> <tcl>hd_fragment jtree {json_tree table-valued function} {json_tree}</tcl> <h2>The json_each() and json_tree() table-valued functions</h2> <p>The json_each(X) and json_tree(X) [table-valued functions] walk the JSON value provided as their first argument and return one row for each element. The json_each(X) function only walks the immediate children of the top-level array or object or or just the top-level element itself if the top-level element is a primitive value. |
︙ | ︙ | |||
617 618 619 620 621 622 623 | <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. | | | 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 | <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. <h3>Examples using json_each() and json_tree()</h3> <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 |
︙ | ︙ |