<acronym>JSON</> Types JSON JSONB JSON data types are for storing JSON (JavaScript Object Notation) data, as specified in RFC 7159. Such data can also be stored as text, but the JSON data types have the advantage of enforcing that each stored value is valid according to the JSON rules. There are also assorted JSON-specific functions available for data stored in these data types; see . There are two JSON data types: json and jsonb. They accept almost identical sets of values as input. The major practical difference is one of efficiency. The json data type stores an exact copy of the input text, which processing functions must reparse on each execution; while jsonb data is stored in a decomposed binary format that makes it slightly slower to input due to added conversion overhead, but significantly faster to process, since it never needs reparsing. jsonb also supports indexing, which can be a significant advantage. Because the json type stores an exact copy of the input text, it will preserve semantically-insignificant white space between tokens, as well as the order of keys within JSON objects. Also, if a JSON object within the value contains the same key more than once, all the key/value pairs are kept. (The processing functions consider the last value as the operative one.) By contrast, jsonb does not preserve white space, does not preserve the order of object keys, and does not keep duplicate object keys. Only the last value for a key specified in the input is kept. jsonb will preserve trailing zeros within a JSON number, even though those are semantically insignificant for purposes such as equality checks. In general, most applications should prefer to store JSON data as jsonb, unless there are quite specialized needs, such as legacy assumptions about ordering of object keys. PostgreSQL allows only one character set encoding per database. It is therefore not possible for the JSON types to conform rigidly to the JSON specification unless the database encoding is UTF-8. Attempts to directly include characters which cannot be represented in the database encoding will fail; conversely, characters which can be represented in the database encoding but not in UTF-8 will be allowed. \uXXXX escapes are allowed regardless of the database encoding, and are checked only for syntactic correctness. Mapping of RFC-7159/JSON Primitive Types to <productname>PostgreSQL</productname> Types JSON scalar types and corresponding <productname>PostgreSQL</productname> types RFC-7159/JSON primitive type PostgreSQL type Notes string text See introductory notes on JSON and encoding number numeric NaN and infinity values are disallowed boolean boolean Only lowercase true and false spellings are accepted null (none) SQL NULL is a different concept
When converting textual JSON input into jsonb, the primitive types described by RFC 7159 are effectively mapped onto native PostgreSQL types, as shown in . Therefore, there are some very minor additional constraints on what constitutes valid jsonb that do not apply to the json type, nor to JSON in the abstract, corresponding to limits on what can be represented by the underlying data type. Specifically, jsonb will reject numbers that are outside the range of the PostgreSQL numeric data type, while json will not. Such implementation-defined restrictions are permitted by RFC 7159. However, in practice such problems are far more likely to occur in other implementations, as it is common to represent the number JSON primitive type as IEEE 754 double precision floating point (which RFC 7159 explicitly anticipates and allows for). When using JSON as an interchange format with such systems, the danger of losing numeric precision compared to data originally stored by PostgreSQL should be considered. Conversely, as noted in the table there are some minor restrictions on the input format of JSON primitive types that do not apply to the corresponding PostgreSQL types.
<type>jsonb</> Input and Output Syntax The input/output syntax for the JSON data types is as specified in RFC 7159. The following are all valid json (or jsonb) expressions: -- Simple scalar/primitive value (explicitly required by RFC-7159) SELECT '5'::json; -- Array of heterogeneous, primitive-typed elements SELECT '[1, 2, "foo", null]'::json; -- Object of heterogeneous key/value pairs of primitive types -- Note that key values are always strings SELECT '{"bar": "baz", "balance": 7.77, "active":false}'::json; Note the distinction between scalar/primitive values as array elements, keys and values. Querying <type>jsonb</type> documents effectively Representing data as JSON can be considerably more flexible than the traditional relational data model, which is compelling in environments where requirements are fluid. It is quite possible for both approaches to co-exist and complement each other within the same application. However, even for applications where maximal flexibility is desired, it is still recommended that JSON documents have a somewhat fixed structure. This structure is typically unenforced (though enforcing some business rules declaratively is possible), but makes it easier to write queries that usefully summarize a set of documents (datums) in a table. json data is subject to the same concurrency control considerations as any other datatype when stored in a table. Although storing large documents is practicable, in order to ensure correct behavior row-level locks are, quite naturally, acquired as rows are updated. Consider keeping json documents at a manageable size in order to decrease lock contention among updating transactions. Ideally, json documents should each represent an atomic datum that business rules dictate cannot reasonably be further subdivided into smaller atomic datums that can be independently modified. <type>jsonb</> containment jsonb containment Testing containment is an important capability of jsonb. There is no parallel set of facilities for the json type. Containment is the ability to determine if one jsonb document has contained within it another one. jsonb is nested, and so containment semantics are nested; technically, top-down, unordered subtree isomorphism may be tested. Containment is conventionally tested using the @> operator, which is made indexable by various operator classes discussed below. -- Simple scalar/primitive values may contain only each other: SELECT '"foo"'::jsonb @> '"foo"'::jsonb; -- The array on the right hand side is contained within the one on the -- left hand side: SELECT '[1, 2, 3]'::jsonb @> '[1, 3]'::jsonb; -- The object with a single pair on the right hand side is contained -- within the object on the left hand side: SELECT '{"product": "PostgreSQL", "version": 9.4, "jsonb":true}'::jsonb @> '{"version":9.4}'::jsonb; -- The array on the right hand side is not contained within the array -- containing a nested array on the left hand side: SELECT '[1, 2, [1, 3]]'::jsonb @> '[1, 3]'::jsonb; -- But with a layer of nesting, it is: SELECT '[1, 2, [1, 3]]'::jsonb @> '[[1, 3]]'::jsonb; It is both a sufficient and a necessary condition for nesting levels to line up for one jsonb to contain within it another. Under this definition, objects and arrays cannot line up, not least because objects contain key/value pairs, while arrays contain elements. As a special exception to the general principle that nesting levels should line up, an array may contain a raw scalar: -- This array contains the raw scalar value: SELECT '["foo", "bar"]'::jsonb @> '"bar"'::jsonb; -- The special exception is not reciprocated -- non-containment is indicated here: SELECT '"bar"'::jsonb @> '["bar"]'::jsonb; Objects are better suited for testing containment when there is a great deal of nesting involved, because unlike arrays they are internally optimized for searching, and do not need to be searched linearly within a single jsonb document. -- The right-hand side object is contained in this example: SELECT '{"p":1, "a":{"b":3, "q":11}, "i":77}'::jsonb @> '{"a":{"b":3}}'::jsonb; The various containment operators, along with all other JSON operators and support functions are documented in . <type>jsonb</> Indexing jsonb indexes on jsonb GIN indexes can be used to efficiently search for keys or key/value pairs occurring within a large number of jsonb documents (datums). Two GIN operator classes are provided, offering different performance and flexibility tradeoffs. The default GIN operator class supports queries with the @>, ?, ?& and ?| operators. (For details of the semantics that these operators implement, see .) An example of creating an index with this operator class is: CREATE INDEX idxgin ON api USING gin (jdoc); The non-default GIN operator class jsonb_hash_ops supports indexing the @> operator only. An example of creating an index with this operator class is: CREATE INDEX idxginh ON api USING gin (jdoc jsonb_hash_ops); Consider the example of a table that stores JSON documents retrieved from a third-party web service, with a documented schema definition. A typical document is: { "guid": "9c36adc1-7fb5-4d5b-83b4-90356a46061a", "name": "Angela Barton", "is_active": true, "company": "Magnafone", "address": "178 Howard Place, Gulf, Washington, 702", "registered": "2009-11-07T08:53:22 +08:00", "latitude": 19.793713, "longitude": 86.513373, "tags": [ "enim", "aliquip", "qui" ] } We store these documents in a table named api, in a jsonb column named jdoc. If a GIN index is created on this column, queries like the following can make use of the index: -- Note that both key and value have been specified SELECT jdoc->'guid', jdoc->'name' FROM api WHERE jdoc @> '{"company": "Magnafone"}'; However, the index could not be used for queries like the following, because though the operator ? is indexable, it is not applied directly to the indexed column jdoc: SELECT jdoc->'guid', jdoc->'name' FROM api WHERE jdoc -> 'tags' ? 'qui'; Still, with judicious use of expression indexes, the above query can use an index scan. If there is a requirement to find those records with a particular tag quickly, and the tags have a high cardinality across all documents, defining an index as follows is an effective approach to indexing: -- Note that the "jsonb -> text" operator can only be called on an -- object, so as a consequence of creating this index the root of each -- "jdoc" value must be an object. This is enforced during insertion. CREATE INDEX idxgintags ON api USING gin ((jdoc -> 'tags')); Now, the WHERE clause jdoc -> 'tags' ? 'qui' will be recognized as an application of the indexable operator ? to the indexed expression jdoc -> 'tags'. (More information on expression indexes can be found in .) Another approach to querying is to exploit containment, for example: SELECT jdoc->'guid', jdoc->'name' FROM api WHERE jdoc @> '{"tags": ["qui"]}'; This approach uses a single GIN index covering everything in the jdoc column, whereas our expression index stored only data found under the tags key. While the single-index approach is certainly more flexible, targeted expression indexes are likely to be smaller and faster to search than a single index. Although the jsonb_hash_ops operator class supports only queries with the @> operator, it has notable performance advantages over the default operator class jsonb_ops. A jsonb_hash_ops GIN index is usually much smaller than a jsonb_ops index over the same data, and the specificity of searches is better, particularly when queries contain tags that appear frequently in the data. Therefore search operations typically perform considerably better than with the default operator class. jsonb also supports btree and hash indexes. These are usually useful only if it's important to check equality of complete JSON documents. The btree ordering for jsonb datums is: Object > Array > Boolean > Number > String > Null Object with n pairs > object with n - 1 pairs Array with n elements > array with n - 1 elements Objects with equal numbers of pairs are compared in the order: key-1, value-1, key-2 ... Note however that object keys are compared in their storage order, and in particular, since shorter keys are stored before longer keys, this can lead to results that might be unintuitive, such as: { "aa": 1, "c": 1} > {"b": 1, "d": 1} Similarly, arrays with equal numbers of elements are compared: element-1, element-2 ... Primitive JSON values are compared using the same comparison rules as for the underlying PostgreSQL data type. Strings are compared using the default database collation.