3 This document describes SQLite's JSONB binary encoding of
8 Beginning with version 3.45.0 (circa 2024-01-01), SQLite supports an
9 alternative binary encoding of JSON which we call "JSONB". JSONB is
10 a binary format that stored as a BLOB.
12 The advantage of JSONB over ordinary text RFC 8259 JSON is that JSONB
13 is both slightly smaller (by between 5% and 10% in most cases) and
14 can be processed in less than half the number of CPU cycles. The built-in
15 [JSON SQL functions] of SQLite can accept either ordinary text JSON
16 or the binary JSONB encoding for any of their JSON inputs.
18 The "JSONB" name is inspired by [PostgreSQL](https://postgresql.org), but the
19 on-disk format for SQLite's JSONB is not the same as PostgreSQL's.
20 The two formats have the same name, but they have wildly different internal
21 representations and are not in any way binary compatible.
23 The central idea behind this JSONB specification is that each element
24 begins with a header that includes the size and type of that element.
25 The header takes the place of punctuation such as double-quotes,
26 curly-brackes, square-brackets, commas, and colons. Since the size
27 and type of each element is contained in its header, the element can
28 be read faster since it is no longer necessary to carefully scan forward
29 looking for the closing delimiter. The payload of JSONB is the same
30 as for corresponding text JSON. The same payload bytes occur in the
31 same order. The only real difference between JSONB and ordinary text
32 JSON is that JSONB includes a binary header on
33 each element and omits delimiter and separator punctuation.
35 ### 1.1 Internal Use Only
37 The details of the JSONB are not intended to be visible to application
38 developers. Application developers should look at JSONB as an opaque BLOB
39 used internally by SQLite. Nevertheless, we want the format to be backwards
40 compatible across all future versions of SQLite. To that end, the format
41 is documented by this file in the source tree. But this file should be
42 used only by SQLite core developers, not by developers of applications
45 ## 2.0 The Purpose Of This Document
47 JSONB is not intended as an external format to be used by
48 applications. JSONB is designed for internal use by SQLite only.
49 Programmers do not need to understand the JSONB format in order to
51 Applications should access JSONB only through the [JSON SQL functions],
52 not by looking at individual bytes of the BLOB.
54 However, JSONB is intended to be portable and backwards compatible
55 for all future versions of SQLite. In other words, you should not have
56 to export and reimport your SQLite database files when you upgrade to
57 a newer SQLite version. For that reason, the JSONB format needs to
60 This document is therefore similar in purpose to the
61 [SQLite database file format] document that describes the on-disk
62 format of an SQLite database file. Applications are not expected
63 to directly read and write the bits and bytes of SQLite database files.
64 The SQLite database file format is carefully documented so that it
65 can be stable and enduring. In the same way, the JSONB representation
66 of JSON is documented here so that it too can be stable and enduring,
67 not so that applications can read or writes individual bytes.
71 JSONB is a direct translation of the underlying text JSON. The difference
72 is that JSONB uses a binary encoding that is faster to parse compared to
73 the detailed syntax of text JSON.
75 Each JSON element is encoded as a header and a payload. The header
76 determines type of element (string, numeric, boolean, null, object, or
77 array) and the size of the payload. The header can be between 1 and
78 9 bytes in size. The payload can be any size from zero bytes up to the
79 maximum allowed BLOB size.
83 The upper four bits of the first byte of the header determine size of the
84 header and possibly also the size of the payload.
85 If the upper four bits have a value between 0 and 11, then the header is
86 exactly one byte in size and the payload size is determined by those
87 upper four bits. If the upper four bits have a value between 12 and 15,
88 that means that the total header size is 2, 3, 5, or 9 bytes and the
89 payload size is unsigned big-endian integer that is contained in the
90 subsequent bytes. The size integer is the one byte that following the
91 initial header byte if the upper four bits
92 are 12, two bytes if the upper bits are 13, four bytes if the upper bits
93 are 14, and eight bytes if the upper bits are 15. The current design
94 of SQLite does not support BLOB values larger than 2GiB, so the eight-byte
95 variant of the payload size integer will never be used by the current code.
96 The eight-byte payload size integer is included in the specification
97 to allow for future expansion.
99 The header for an element does *not* need to be in its simplest
100 form. For example, consider the JSON numeric value "`1`".
101 That element can be encode in five different ways:
105 * `0xd3 0x00 0x01 0x31`
106 * `0xe3 0x00 0x00 0x00 0x01 0x31`
107 * `0xf3 0x00 0x00 0x00 0x00 0x00 0x00 0x00 0x01 0x31`
109 The shortest encoding is preferred, of course, and usually happens with
110 primitive elements such as numbers. However the total size of an array
111 or object might not be known exactly when the header of the element is
112 first generated. It is convenient to reserve space for the largest
113 possible header and then go back and fill in the correct payload size
114 at the end. This technique can result in array or object headers that
115 are larger than absolutely necessary.
119 The least-significant four bits of the first byte of the header (the first
120 byte masked against 0x0f) determine element type. The following codes are
124 <li type="0"><p><b>NULL</b> →
125 The element is a JSON "null". The payload size for a true JSON NULL must
126 must be zero. Future versions of SQLite might extend the JSONB format
127 with elements that have a zero element type but a non-zero size. In that
128 way, legacy versions of SQLite will interpret the element as a NULL
129 for backwards compatibility while newer versions will interpret the
130 element in some other way.
132 <li value="1"><p><b>TRUE</b> →
133 The element is a JSON "true". The payload size must be zero for a actual
134 "true" value. Elements with type 1 and a non-zero payload size are
135 reserved for future expansion. Legacy implementations that see an element
136 type of 1 with a non-zero payload size should continue to interpret that
137 element as "true" for compatibility.
139 <li value="2"><p><b>FALSE</b> →
140 The element is a JSON "false". The payload size must be zero for a actual
141 "false" value. Elements with type 2 and a non-zero payload size are
142 reserved for future expansion. Legacy implementations that see an element
143 type of 2 with a non-zero payload size should continue to interpret that
144 element as "false" for compatibility.
146 <li value="3"><p><b>INT</b> →
147 The element is a JSON integer value in the canonical
148 RFC 8259 format, without extensions. The payload is the ASCII
149 text representation of that numeric value.
151 <li value="4"><p><b>INT5</b> →
152 The element is a JSON integer value that is not in the
153 canonical format. The payload is the ASCII
154 text representation of that numeric value. Because the payload is in a
155 non-standard format, it will need to be translated when the JSONB is
156 converted into RFC 8259 text JSON.
158 <li value="5"><p><b>FLOAT</b> →
159 The element is a JSON floating-point value in the canonical
160 RFC 8259 format, without extensions. The payload is the ASCII
161 text representation of that numeric value.
163 <li value="6"><p><b>FLOAT5</b> →
164 The element is a JSON floating-point value that is not in the
165 canonical format. The payload is the ASCII
166 text representation of that numeric value. Because the payload is in a
167 non-standard format, it will need to be translated when the JSONB is
168 converted into RFC 8259 text JSON.
170 <li value="7"><p><b>TEXT</b> →
171 The element is a JSON string value that does not contain
172 any escapes nor any characters that need to be escaped for either SQL or
173 JSON. The payload is the UTF8 text representation of the string value.
174 The payload does <i>not</i> include string delimiters.
176 <li value="8"><p><b>TEXTJ</b> →
177 The element is a JSON string value that contains
178 RFC 8259 character escapes (such as "<tt>\n</tt>" or "<tt>\u0020</tt>").
179 Those escapes will need to be translated into actual UTF8 if this element
180 is [json_extract|extracted] into SQL.
181 The payload is the UTF8 text representation of the escaped string value.
182 The payload does <i>not</i> include string delimiters.
184 <li value="9"><p><b>TEXT5</b> →
185 The element is a JSON string value that contains
186 character escapes, including some character escapes that part of JSON5
187 and which are not found in the canonical RFC 8259 spec.
188 Those escapes will need to be translated into standard JSON prior to
189 rendering the JSON as text, or into their actual UTF8 characters if this
190 element is [json_extract|extracted] into SQL.
191 The payload is the UTF8 text representation of the escaped string value.
192 The payload does <i>not</i> include string delimiters.
194 <li value="10"><p><b>TEXTRAW</b> →
195 The element is a JSON string value that contains
196 UTF8 characters that need to be escaped if this string is rendered into
198 The payload does <i>not</i> include string delimiters.
200 <li value="11"><p><b>ARRAY</b> →
201 The element is a JSON array. The payload contains
202 JSONB elements that comprise values contained within the array.
204 <li value="12"><p><b>OBJECT</b> →
205 The element is a JSON object. The payload contains
206 pairs of JSONB elements that comprise entries for the JSON object.
207 The first element in each pair must be a string (types 7 through 10).
208 The second element of each pair may be any types, including nested
211 <li value="13"><p><b>RESERVED-13</b> →
212 Reserved for future expansion. Legacy implements that encounter this
213 element type should raise an error.
215 <li value="14"><p><b>RESERVED-14</b> →
216 Reserved for future expansion. Legacy implements that encounter this
217 element type should raise an error.
219 <li value="15"><p><b>RESERVED-15</b> →
220 Reserved for future expansion. Legacy implements that encounter this
221 element type should raise an error.
224 Element types outside the range of 0 to 12 are reserved for future
225 expansion. The current implement raises an error if see an element type
226 other than those listed above. However, future versions of SQLite might
227 use of the three remaining element types to implement indexing or similar
228 optimizations, to speed up lookup against large JSON arrays and/or objects.
230 ### 3.3 Design Rationale For Element Types
232 A key goal of JSONB is that it should be quick to translate
233 to and from text JSON and/or be constructed from SQL values.
234 When converting from text into JSONB, we do not want the
235 converter subroutine to burn CPU cycles converting elements
236 values into some standard format which might never be used.
237 Format conversion is "lazy" - it is deferred until actually
238 needed. This has implications for the JSONB format design:
240 1. Numeric values are stored as text, not a numbers. The values are
241 a direct copy of the text JSON values from which they are derived.
243 2. There are multiple element types depending on the details of value
244 formats. For example, INT is used for pure RFC-8259 integer
245 literals and INT5 exists for JSON5 extensions such as hexadecimal
246 notation. FLOAT is used for pure RFC-8259 floating point literals
247 and FLOAT5 is used for JSON5 extensions. There are four different
248 representations of strings, depending on where the string came from
249 and how special characters within the string are escaped.
251 A second goal of JSONB is that it should be capable of serving as the
252 "parse tree" for JSON when a JSON value is being processed by the
253 various [JSON SQL functions] built into SQLite. Before JSONB was
254 developed, operations such [json_replace()] and [json_patch()]
255 and similar worked in three stages:
258 1. Translate the text JSON into a internal format that is
259 easier to scan and edit.
260 2. Perform the requested operation on the JSON.
261 3. Translate the internal format back into text.
263 JSONB seeks to serve as the internal format directly - bypassing
264 the first and third stages of that process. Since most of the CPU
265 cycles are spent on the first and third stages, that suggests that
266 JSONB processing will be much faster than text JSON processing.
268 So when processing JSONB, only the second stage of the three-stage
269 process is required. But when processing text JSON, it is still necessary
270 to do stages one and three. If JSONB is to be used as the internal
271 binary representation, this is yet another reason to store numeric
272 values as text. Storing numbers as text minimizes the amount of
273 conversion work needed for stages one and three. This is also why
274 there are four different representations of text in JSONB. Different
275 text representations are used for text coming from different sources
276 (RFC-8259 JSON, JSON5, or SQL string values) and conversions only
277 happen if and when they are actually needed.
279 ### 3.4 Valid JSONB BLOBs
281 A valid JSONB BLOB consists of a single JSON element. The element must
282 exactly fill the BLOB. This one element is often a JSON object or array
283 and those usually contain additional elements as its payload, but the
284 element can be a primite value such a string, number, boolean, or null.
286 When the built-in JSON functions are attempting to determine if a BLOB
287 argument is a JSONB or just a random BLOB, they look at the header of
288 the outer element to see that it is well-formed and that the element
289 completely fills the BLOB. If these conditions are met, then the BLOB
290 is accepted as a JSONB value.