Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Add a how-to-compile section to the json1 documentation. And fix many typos. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
aafe027cf00e214f2fd7754ea7f3cb9e |
User & Date: | drh 2015-09-10 18:21:35.254 |
Context
2015-09-10
| ||
18:51 | Fix another typo in the json1 documentation. (check-in: 0fcd73bb5a user: drh tags: trunk) | |
18:21 | Add a how-to-compile section to the json1 documentation. And fix many typos. (check-in: aafe027cf0 user: drh tags: trunk) | |
17:21 | Update the json1 documentation to describe the new "path" column of json_tree(). (check-in: 5cc19499aa user: drh tags: trunk) | |
Changes
Changes to pages/json1.in.
︙ | ︙ | |||
47 48 49 50 51 52 53 | } 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)} { | | | < | | | | | | | > | 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 | } 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 the arguments. } jarraylen tabentry {json_extract(json,path,...)} { Extract values or subcomponents from a JSON string. } jex tabentry {json_insert(json,path,value,...)} { Insert values into a JSON string without overwriting existing values. } jins tabentry {json_object(label1,value1,...)} { Construct and return a new JSON object based on the arguments. } jobj tabentry {json_remove(json,path,...)} { Remove the specified values from a JSON string. } jrm tabentry {json_replace(json,path,value,...)} { Update existing values within a JSON string. } jrepl tabentry {json_set(json,path,value,...)} { Insert or replace values in JSON string. Overwrite existing elements or create new entries in the JSON string for elements that do not previously exist. } jset tabentry {json_type(json)<br>json_type(json,path)} { Return the type of a JSON string or subcomponent. } jtype tabentry {json_valid(json)} { |
︙ | ︙ | |||
103 104 105 106 107 108 109 | tabentry {json_tree(json)<br>json_tree(json,path)} { 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> | > | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 | tabentry {json_tree(json)<br>json_tree(json,path)} { 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> <h2>1.0 Compiling the JSON1 Extension</h2> <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 module can also be statically linked against SQLite in either of two ways: <ol> <li><p> Compile the ext/misc/json1.c source file separately using the additional -DSQLITE_CORE compile-time option. Then link the resulting json1.o object file with the application. <li><p> Append the ext/misc/json1.c source file onto the end of a standard [amalgamation|sqlite3.c amalagamation] source file and compile them together. No -DSQLITE_CORE compile-time option is needed in this case since the SQLITE_CORE C preprocessor macro is defined by the code in sqlite3.c. </ol> <p> In both cases, one can add the -DSQLITE_ENABLE_JSON1 compile-time option while compiling sqlite3.c file. The SQLITE_ENABLE_JSON1 option causes SQLite to automatically register the json1 extension with each no connection that is opened. <p> Note that the [command-line shell] already statically links json1 when built using any of the standard makefiles. So the JSON functions described here are automatically available in the command-line shell. <h2>2.0 Interface Overview</h2> <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, |
︙ | ︙ | |||
127 128 129 130 131 132 133 | 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 json1 extension might be enhanced in the future to support a JSONB sub-type that is stored as a BLOB. <p> | | | | | | | | | | | 164 165 166 167 168 169 170 171 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 215 216 217 218 219 220 221 222 223 224 | 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 json1 extension might be enhanced in the future to support a JSONB sub-type that is stored as a BLOB. <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, JSON support remains an extension. <h3>2.1 JSON arguments</h3> <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. (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. <p> Passing in a BLOB value as JSON always causes an error to be thrown (except by the json_valid() function, which instead returns 0.) The json1 extension may be enhanced in the future to interpret BLOB values as a binary encoding of JSON. <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 one or in some cases two '$' characters. The last '$' can be followed by zero or more instances of ".<i>objectlabel</i>" or "[<i>arrayindex</i>]". <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 jarray {json_array SQL function} {json_array}</tcl> <h3>3.1 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>In the current implementation, if an argument to json_array() is text that looks like JSON, it is quoted and interpreted as a single |
︙ | ︙ | |||
199 200 201 202 203 204 205 | {json_array(1,null,'3','[4,5]','{"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> | | | | | | | | | | | | | | 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 296 297 298 299 300 301 302 303 304 305 306 | {json_array(1,null,'3','[4,5]','{"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.2 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.3 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 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 </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.4 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. <center> <table border=1 cellpadding=3> <tr> <th>Function<th>Overwrite if already exists?<th>Create if does not exist? |
︙ | ︙ | |||
282 283 284 285 286 287 288 | 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>Path arguments in json_insert(), json_replace(), and json_set() are allowed to have either one or two initial '$' characters. If the path | | | | 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 | 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>Path arguments in json_insert(), json_replace(), and json_set() are allowed to have either one or two initial '$' characters. If the path has one initial '$' character, then SQLite text values are quoted and inserted as JSON strings. If the path has two initial '$' characters, then SQLite text values are inserted as JSON array or object values. <p>Future versions of this extension that support the JSON sub-type for text will always insert as JSON objects or arrays any string that has a sub-type of JSON and will only quote and insert values as JSON strings if the input value is not of sub-type JSON. |
︙ | ︙ | |||
309 310 311 312 313 314 315 | {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}'} </tcl> <tcl>hd_fragment jobj {json_object SQL function} {json_object}</tcl> | | | | | | | | | | | | | | | | | | | 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 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 | {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}'} </tcl> <tcl>hd_fragment jobj {json_object SQL function} {json_object}</tcl> <h3>3.5 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>In the current implementation, if a value argument to json_object() is text that looks like JSON, it is quoted and interpreted as a single JSON string value. In future enhancements in which a SQLite text value can have a sub-type of "JSON", this routine will insert substructure instead of a single string value. Please beware of this future incompatibility and plan accordingly. <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}"}'} </tcl> <tcl>hd_fragment jrm {json_remove SQL function} {json_remove}</tcl> <h3>3.6 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. <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, then it returns the input X reformatted, with excess whitespace removed. <p>The json_remove() function throws an error if the first argument is not well-formed JSON or if any later argument is not a well-formed path, or if any argument is a BLOB. <p>Examples: <tcl> jexample \ {json_remove('[0,1,2,3,4]','$[2]')} {'[0,1,3,4]'} \ {json_remove('[0,1,2,3,4]','$[2]','$[0]')} {'[1,3,4]'} \ {json_remove('[0,1,2,3,4]','$[0]','$[2]')} {'[1,2,4]'} \ {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> <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 an SQL text value which is one of the following: '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 the function returns NULL. <p>The json_type() function throws an error if any of its arguments are not well-formed or are a BLOB. <p>Examples: <tcl> |
︙ | ︙ | |||
401 402 403 404 405 406 407 | {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> | | | | | | | | | | 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 468 469 470 471 472 473 474 475 476 477 478 479 | {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.8 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> jexample \ {json_valid('{"x":35}')} 1 \ "json_valid('\173\"x\":35')" 0 </tcl> <tcl>hd_fragment jeach {json_each table-valued function} {json_each}</tcl> <tcl>hd_fragment jtree {json_tree table-valued function} {json_tree}</tcl> <h3>3.9 The json_each() and json_tree() table-valued functions</h3> <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. The json_tree(X) function recursively walks through the JSON substructure starting with the top-level element. <p>The json_each(X,P) and json_tree(X,P) functions work just like their one-argument counterparts except that they treat the element identified by path P as the top-level element. <p>The schema for the table returned by json_each() and json_tree() is as follows: <blockquote><pre> |
︙ | ︙ | |||
492 493 494 495 496 497 498 | <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. | | | | | > | 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 | <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.9.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 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. We ask the same question: "Which uses 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 single 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) WHERE json_valid(user.phone) |
︙ | ︙ |
Changes to pages/loadext.in.
︙ | ︙ | |||
12 13 14 15 16 17 18 | This feature allows the code for extensions to be developed and tested separately from the application and then loaded on an as-needed basis.</p> <p>Extensions can also be statically linked with the application. The code template shown below will work just as well as a statically linked extension as it does as a run-time loadable extension except that | | | 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 | This feature allows the code for extensions to be developed and tested separately from the application and then loaded on an as-needed basis.</p> <p>Extensions can also be statically linked with the application. The code template shown below will work just as well as a statically linked extension as it does as a run-time loadable extension except that you should give the entry point function ("sqlite3_extension_init") a different name to avoid name collisions if your application contains two or more extensions.</p> <h2>Loading An Extension</h2> <p>An SQLite extension is a shared library or DLL. To load it, you need to supply SQLite with the name of the file containing the |
︙ | ︙ | |||
81 82 83 84 85 86 87 | point with a different name, simply supply that name as the second argument. For example:</p> <blockquote><pre> .load ./YourCode nonstandard_entry_point </pre></blockquote> | | > | 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 | point with a different name, simply supply that name as the second argument. For example:</p> <blockquote><pre> .load ./YourCode nonstandard_entry_point </pre></blockquote> <tcl>hd_fragment build {Compiling Loadable Extensions} \ {compile loadable extensions}</tcl> <h2>Compiling A Loadable Extension</h2> <p>Loadable extensions are C-code. To compile them on most unix-like operating systems, the usual command is something like this:</p> <blockquote><pre> |
︙ | ︙ | |||
110 111 112 113 114 115 116 | on how your application is built.</p> <p>To compile on Windows using MSVC, a command similar to the following will usually work:</p> <blockquote><pre> cl YourCode.c -link -dll -out:YourCode.dll | | | 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 | on how your application is built.</p> <p>To compile on Windows using MSVC, a command similar to the following will usually work:</p> <blockquote><pre> cl YourCode.c -link -dll -out:YourCode.dll </pre></blockquote> <p>To compile for Windows using MinGW, the command line is just like it is for unix except that the output file suffix is changed to ".dll" and the -fPIC argument is omitted:</p> <blockquote><pre> gcc -g -shared YourCode.c -o YourCode.dll |
︙ | ︙ |