JavaScript Object Notation (JSON) data types are used for storing JSON data.
It can be an independent scalar, an array, or a key-value object. An array and an object can be called a container.
GaussDB(DWS) supports the json and jsonb data types to store JSON data. Where:
Both JSON and JSONB are of JSON data type, and the same strings can be entered as input. The main difference between JSON and JSONB is the efficiency. Because json data is an exact copy of the input text, the data must be parsed on every execution. In contrast, jsonb data is stored in a decomposed binary form and can be processed faster, though this makes it slightly slower to input due to the conversion mechanism. In addition, because the JSONB data form is normalized, it supports more operations, for example, comparing sizes according to a specific rule. JSONB also supports indexing, which is a significant advantage.
The input must be a JSON-compliant string, which is enclosed in single quotation marks ('').
Null (null-json): Only null is supported, and all letters are in lowercase.
1 2 | SELECT 'null'::json; -- suc SELECT 'NULL'::jsonb; -- err |
Number (num-json): The value can be a positive or negative integer, decimal fraction, or 0. The scientific notation is supported.
1 2 3 4 | SELECT '1'::json; SELECT '-1.5'::json; SELECT '-1.5e-5'::jsonb, '-1.5e+2'::jsonb; SELECT '001'::json, '+15'::json, 'NaN'::json; -- Redundant leading zeros, plus signs (+), NaN, and infinity are not supported. |
Boolean (bool-json): The value can only be true or false in lowercase.
1 2 | SELECT 'true'::json; SELECT 'false'::jsonb; |
String (str-json): The value must be a string enclosed in double quotation marks ("").
1 2 | SELECT '"a"'::json; SELECT '"abc"'::jsonb; |
Array (array-json): Arrays are enclosed in square brackets ([]). Elements in the array can be any valid JSON data, and are unnecessarily of the same type.
1 2 3 | SELECT '[1, 2, "foo", null]'::json; SELECT '[]'::json; SELECT '[1, 2, "foo", null, [[]], {}]'::jsonb; |
Object (object-json): The value is enclosed in braces ({}). The key must be a JSON-compliant string, and the value can be any valid JSON string.
1 2 3 | SELECT '{}'::json; SELECT '{"a": 1, "b": {"a": 2, "b": null}}'::json; SELECT '{"foo": [true, "bar"], "tags": {"a": 1, "b": null}}'::jsonb; |
The main difference between JSON and JSONB is the storage mode. JSONB stores parsed binary data, which reflects the JSON hierarchy and facilitates direct access. Therefore, JSONB has more advanced features than JSON.
Normalizes formats
1 2 3 4 5 | SELECT ' [1, " a ", {"a" :1 }] '::jsonb; jsonb ---------------------- [1, " a ", {"a": 1}] (1 row) |
1 2 3 4 5 | SELECT '{"a" : 1, "a" : 2}'::jsonb; jsonb ---------- {"a": 2} (1 row) |
1 2 3 4 5 | SELECT '{"aa" : 1, "b" : 2, "a" : 3}'::jsonb; jsonb --------------------------- {"a": 3, "b": 2, "aa": 1} (1 row) |
Compares sizes
Format normalization ensures that only one form of JSONB data exists in the same semantics. Therefore, sizes can be compared according to a specific rule.
For comparison within the object-jsonb type, the final result after format sorting is used for comparison. Therefore, the comparison result may not be so intuitive as direct input.
Creates an index
B-Tree and GIN indexes can be created for the JSONB type.
If the entire JSONB column uses a Btree index, the following operators can be used: =, <, <=, >, and >=.
Example: Create the table test and insert data into it.
1 2 | CREATE TABLE test(id bigserial, data JSONB, PRIMARY KEY (id)); INSERT INTO test(data) VALUES('{"name":"Jack", "age":10, "nick_name":["Jacky","baobao"], "phone_list":["1111","2222"]}'::jsonb); |
1 | CREATE INDEX idx_test_data_age ON test USING btree(((data->>'age')::int)); |
1 | SELECT * FROM test WHERE (data->>'age')::int>1; |
1 | CREATE INDEX idx_test_data ON test USING gin (data); |
1 2 | SELECT * FROM test WHERE data ? 'id'; SELECT * FROM test WHERE data ?| array['id','name']; |
1 2 | CREATE INDEX idx_test_data_nick_name ON test USING gin((data->'nick_name')); SELECT * FROM test WHERE data->'nick_name' ? 'Jacky'; |
1 | SELECT * FROM test WHERE data @> '{"age":10, "nick_name":["Jacky"]}'; |
Includes elements in a JSON
An important capability of JSONB is to query whether a JSON contains some elements or whether some elements exist in a JSON.
1 | SELECT '"foo"'::jsonb @> '"foo"'::jsonb; |
1 | SELECT '[1, "aa", 3]'::jsonb ? 'aa'; |
1 | SELECT '[1, 2, 3]'::jsonb @> '[1, 3, 1]'::jsonb; |
1 | SELECT '{"product": "PostgreSQL", "version": 9.4, "jsonb":true}'::jsonb @> '{"version":9.4}'::jsonb; |
1 | SELECT '[1, 2, [1, 3]]'::jsonb @> '[1, 3]'::jsonb; -- false |
1 | SELECT '{"foo": {"bar": "baz"}}'::jsonb @> '{"bar": "baz"}'::jsonb; -- false |