Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | First draft of json1 documentation. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
ea6f64590bbdd1618cf2e98fb32346d5 |
User & Date: | drh 2015-09-09 02:04:42.555 |
Context
2015-09-09
| ||
02:06 | Fix a typo in the json1 documentation. (check-in: 57b4eafa71 user: drh tags: trunk) | |
02:04 | First draft of json1 documentation. (check-in: ea6f64590b user: drh tags: trunk) | |
2015-09-08
| ||
21:33 | Improved documentation for table-valued functions and eponymous virtual tables. (check-in: 9b1f04e2d1 user: drh tags: trunk) | |
Changes
Changes to pages/changes.in.
︙ | ︙ | |||
22 23 24 25 26 27 28 | <p><b>New Features And Enhancements:</b> <li>The [CREATE VIEW] statement now accepts an optional list of column names following the view name. <li>Added support for [indexes on expressions]. <li>Added support for [table-valued functions] in the FROM clause of a [SELECT] statement. <li>Added support for [eponymous virtual tables]. | | | 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 | <p><b>New Features And Enhancements:</b> <li>The [CREATE VIEW] statement now accepts an optional list of column names following the view name. <li>Added support for [indexes on expressions]. <li>Added support for [table-valued functions] in the FROM clause of a [SELECT] statement. <li>Added support for [eponymous virtual tables]. <li>Added [the json1 extension] module in the source tree. <li>A [VIEW] may now reference undefined tables and functions when initially created. Missing tables and functions are reported when the VIEW is used in a query. <li>The query planner is now able to use [partial indexes] that contain AND-connected terms in the WHERE clause. <li>The sqlite3_analyzer.exe utility is updated to report the depth of each btree and to show the average fanout for indexes and |
︙ | ︙ |
Added pages/json1.in.
> > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | 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 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 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 89 90 91 92 93 94 95 96 97 98 99 100 101 102 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 155 156 157 158 159 160 161 162 163 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 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 296 297 298 299 300 301 302 303 304 305 306 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 | <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 ten [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_[a-z_]+)} $fx "$hlink\\1</a>" fx regsub -all {(value?|path|label?)} $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" } 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 a JSON array holding the function arguments. The optional "path" argument specifies the location of the array in a larger JSON object. } jarraylen tabentry {json_extract(json,path)} { Extract a value from a JSON string. } jex tabentry {json_insert(json,path,value,...)} { Insert one or more values into a JSON string. } jins tabentry {json_object(label1,value1,...)} { Construct and return a new JSON object based on the arguments. } jobj tabentry {json_remove(json,path,...)} { Remove one or more values from a JSON string. } jrm tabentry {json_replace(json,path,value,...)} { Replace one or more in a JSON string with new values supplied. } jrepl tabentry {json_set(json,path,value,...)} { Insert or replace one or more values in a JSON string with new values supplied } jset 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>The [table-valued functions] implemented by this routine are: <blockquote><center><table border=0 cellpadding=5> <tcl> tabentry {json_each(json)<br>json_each(json,path)} { Return one row describing each element in an array or object at the top-level or at "path" within the input JSON. } jeach tabentry {json_tree(json)<br>json_tree(json,path)} { Walk the JSON recursively and return one row for each element. } jtree </tcl> </table></center></blockquote> <h2>1.0 Ground Rules</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, and BLOBs. It is not possible add a sixth "JSON" type. Future versions of SQLite might be extended to support the concept of a "sub-type" for text and BLOB values. If and when that enhancement is implemented, there will be a JSON "sub-type" available to values of type "text". <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 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 this 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>1.1 JSON arguments</h3> <p> For functions that accept JSON as their first argument, that argument can be any JSON an 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 except 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.) This extension may be enhanced in the future to interpret some BLOB values as a binary encoding of JSON. <h3>1.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>2.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>2.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 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. <tcl>hd_fragment jarraylen {json_array_length SQL function} \ {json_array_length}</tcl> <h3>2.2 The json_array_length() function</h3> <p>The json_array_length(J) function returns the number of elements in the JSON array J, or 0 if J is some kind of JSON value other than an array. The json_array_length(J,P) locates the array at path P within J and returns the length of that array, or 0 if path P does not locate an array within J. Errors are thrown if either J is not well-formed JSON or if P is not a well-formed path. <tcl>hd_fragment jex {json_extract SQL function} {json_extract}</tcl> <h3>2.3 The json_extract() function</h3> <p>The json_extract(J,P1,P2,...) extracts and returns one or more values from the well-formed JSON at J. 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 an SQLite text which is a well-formed JSON array holding the various values. <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>2.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 paths and values. 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? <tr> <td>json_insert()<td align='center'>No<td align='center'>Yes <tr> <td>json_replace()<td align='center'>Yes<td align='center'>No <tr> <td>json_insert()<td align='center'>Yes<td align='center'>Yes </table></center> <p>The json_insert(), json_replace(), and json_set() functions always take an odd number of arguments. The first argument is always the original 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>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 value are quoted and inserted as if they are JSON string values. 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. <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. <tcl>hd_fragment jobj {json_object SQL function} {json_object}</tcl> <h3>2.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_array() is a BLOB then an error is thrown. <p>The json_object() function does not currently object to having duplicate labels, 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. <tcl>hd_fragment jrm {json_remove SQL function} {json_remove}</tcl> <h3>2.6 The json_remove() function</h3> <p>The json_remove(J,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(J,P,...) function returns a new JSON value that is the input J value with all the elements identified by path arguments removed. Paths that select elements not found in J 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(J) function is called with no path arguments, then it returns the input J 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. <tcl>hd_fragment jtype {json_type SQL function} {json_type}</tcl> <h3>2.7 The json_type() function</h3> <p>The json_type(J) function returns the "type" of the outermost element of J. The json_type(J,P) function returns the "type" of the element in J 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(J,P) selects a element that does not exist in J, 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. <tcl>hd_fragment jvalid {json_valid SQL function} {json_valid}</tcl> <h3>2.8 The json_valid() function</h3> <p>The json_valid(J) function return 1 if the argument J is well-formed JSON and return 0 if the argument J is not well-formed JSON. <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>2.9 The json_each() and json_tree() table-valued functions</h3> <p>The json_each(J) and json_tree(J) [table-valued functions] walk the JSON value provided as their first argument and return one row for each element. The json_each(J) function only walks the top-level element (which is presumably an array or object) and does not descend into substructure. The json_tree(J) function recursively walks through the JSON substructure. Other than the fact that json_tree(J) recursively descends through JSON substructure, the json_tree(J) and json_each(J) functions are the same. <p>The schema for the table returned by json_each() and json_tree() is as follows: <blockquote><pre> CREATE TABLE json_tree( key ANY, -- key for current element relative to its parent value ANY, -- value for the current element type TEXT, -- 'object','array','string','integer', etc. atom ANY, -- value for primitive types, null for array & object id INTEGER -- integer ID for this element parent INTEGER, -- integer ID for the parent of this element fullkey TEXT, -- full path describing the current element json JSON HIDDEN, -- 1st input parameter: the raw JSON path TEXT HIDDEN -- 2nd input parameter: the PATH at which to start ); </pre></blockquote> <p> The "key" column is the integer array index for elements of a JSON array and the text label for elements of a JSON object. The key column is NULL in all other cases. <p> The "atom" column is the SQL value corresponding to primitive elements - elements other than JSON arrays and objects. The "atom" column is NULL for a JSON array or object. The "value" column is the same as the "atom" column for primitive JSON elements but takes on the text JSON value for arrays and objects. <p> The "type" column is an SQL text value taken from ('null', 'true', 'false', 'integer', 'real', 'text', 'array', 'object') according to the type of the current JSON element. <p> The "id" column is an integer that identifies a specific JSON element within the complete JSON string. The "id" integer is an internal housekeeping number, the computation of which might change in future releases. The only guarantee is that the "id" column will be different for every row. <p> The "parent" column is the "id" integer for the parent of the current element, or NULL for the top-level JSON element. <p> The "fullkey" column is a text path that uniquely identifies the current row element within the original JSON string. <h2>3.0 Examples</h2> |