Bu sayfa henüz yerel dilinizde mevcut değildir. Daha fazla dil seçeneği eklemek için yoğun bir şekilde çalışıyoruz. Desteğiniz için teşekkür ederiz.

Compute
Elastic Cloud Server
Huawei Cloud Flexus
Bare Metal Server
Auto Scaling
Image Management Service
Dedicated Host
FunctionGraph
Cloud Phone Host
Huawei Cloud EulerOS
Networking
Virtual Private Cloud
Elastic IP
Elastic Load Balance
NAT Gateway
Direct Connect
Virtual Private Network
VPC Endpoint
Cloud Connect
Enterprise Router
Enterprise Switch
Global Accelerator
Management & Governance
Cloud Eye
Identity and Access Management
Cloud Trace Service
Resource Formation Service
Tag Management Service
Log Tank Service
Config
OneAccess
Resource Access Manager
Simple Message Notification
Application Performance Management
Application Operations Management
Organizations
Optimization Advisor
IAM Identity Center
Cloud Operations Center
Resource Governance Center
Migration
Server Migration Service
Object Storage Migration Service
Cloud Data Migration
Migration Center
Cloud Ecosystem
KooGallery
Partner Center
User Support
My Account
Billing Center
Cost Center
Resource Center
Enterprise Management
Service Tickets
HUAWEI CLOUD (International) FAQs
ICP Filing
Support Plans
My Credentials
Customer Operation Capabilities
Partner Support Plans
Professional Services
Analytics
MapReduce Service
Data Lake Insight
CloudTable Service
Cloud Search Service
Data Lake Visualization
Data Ingestion Service
GaussDB(DWS)
DataArts Studio
Data Lake Factory
DataArts Lake Formation
IoT
IoT Device Access
Others
Product Pricing Details
System Permissions
Console Quick Start
Common FAQs
Instructions for Associating with a HUAWEI CLOUD Partner
Message Center
Security & Compliance
Security Technologies and Applications
Web Application Firewall
Host Security Service
Cloud Firewall
SecMaster
Anti-DDoS Service
Data Encryption Workshop
Database Security Service
Cloud Bastion Host
Data Security Center
Cloud Certificate Manager
Edge Security
Situation Awareness
Managed Threat Detection
Blockchain
Blockchain Service
Web3 Node Engine Service
Media Services
Media Processing Center
Video On Demand
Live
SparkRTC
MetaStudio
Storage
Object Storage Service
Elastic Volume Service
Cloud Backup and Recovery
Storage Disaster Recovery Service
Scalable File Service Turbo
Scalable File Service
Volume Backup Service
Cloud Server Backup Service
Data Express Service
Dedicated Distributed Storage Service
Containers
Cloud Container Engine
Software Repository for Container
Application Service Mesh
Ubiquitous Cloud Native Service
Cloud Container Instance
Databases
Relational Database Service
Document Database Service
Data Admin Service
Data Replication Service
GeminiDB
GaussDB
Distributed Database Middleware
Database and Application Migration UGO
TaurusDB
Middleware
Distributed Cache Service
API Gateway
Distributed Message Service for Kafka
Distributed Message Service for RabbitMQ
Distributed Message Service for RocketMQ
Cloud Service Engine
Multi-Site High Availability Service
EventGrid
Dedicated Cloud
Dedicated Computing Cluster
Business Applications
Workspace
ROMA Connect
Message & SMS
Domain Name Service
Edge Data Center Management
Meeting
AI
Face Recognition Service
Graph Engine Service
Content Moderation
Image Recognition
Optical Character Recognition
ModelArts
ImageSearch
Conversational Bot Service
Speech Interaction Service
Huawei HiLens
Video Intelligent Analysis Service
Developer Tools
SDK Developer Guide
API Request Signing Guide
Terraform
Koo Command Line Interface
Content Delivery & Edge Computing
Content Delivery Network
Intelligent EdgeFabric
CloudPond
Intelligent EdgeCloud
Solutions
SAP Cloud
High Performance Computing
Developer Services
ServiceStage
CodeArts
CodeArts PerfTest
CodeArts Req
CodeArts Pipeline
CodeArts Build
CodeArts Deploy
CodeArts Artifact
CodeArts TestPlan
CodeArts Check
CodeArts Repo
Cloud Application Engine
MacroVerse aPaaS
KooMessage
KooPhone
KooDrive
On this page

JSON Types

Updated on 2024-09-02 GMT+08:00

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.

  1. Scalar: a number, Boolean, string, or null
  2. Array: defined in a pair of square brackets ([]), in which elements can be of any JSON data type, and are not necessarily of the same type.
  3. Object: defined in a pair of braces ({}), in which objects are stored in the format of key:value. Each key must be a string enclosed in double quotation marks (""), and its value can be of any JSON data type. In case of duplicate keys, the last key-value pair will be used.

GaussDB(DWS) supports the json and jsonb data types to store JSON data. Where:

  • json copies all entered strings and parses them when they are used. During this process, the entered spaces, duplicate keys, and sequence are retained.
  • jsonb parses the binary data of the input. During parsing, jsonb deletes semantic-irrelevant details and duplicate keys, and sorts key values, so that the data does not to be parsed again during use.

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.

Input Format

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; 
CAUTION:
  • Note that 'null'::json and null::json are different. The difference is similar to that between the strings str="" and str=null.
  • For numbers, when scientific notation is used, JSONB expands them, while JSON stores an exact copy of the input text.

JSONB Advanced Features

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

  • After the input object-json string is parsed into JSONB binary, semantically irrelevant details are naturally discarded, for example, spaces:
    1
    2
    3
    4
    5
    SELECT '   [1, " a ", {"a"   :1    }]  '::jsonb;
        jsonb
    ----------------------
    [1, " a ", {"a": 1}]
    (1 row)
    
  • For object-json, duplicate key-values are deleted and only the last key-value is retained. An example is as follows:
    1
    2
    3
    4
    5
    SELECT '{"a" : 1, "a" : 2}'::jsonb;
    jsonb
    ----------
    {"a": 2}
    (1 row)
    
  • For object-json, key-values will be re-sorted. The sorting rule is as follows: 1. Longer key-values are sorted last. 2. If the key-values are of the same length, the key-values with a larger ASCII code are sorted last. An example is as follows:
    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.

  1. First, type comparison: object-jsonb > array-jsonb > bool-jsonb > num-jsonb > str-jsonb > null-jsonb
  2. Content is compared if the data type is the same:
    • str-json: The default text sorting rule of the database is used for comparison. A positive value indicates greater than, a negative value indicates less than, and 0 indicates equal.
    • num-json: numeric comparison
    • bool-json: true > false
    • array-jsonb: long elements > short elements. If the lengths are the same, compare each element in sequence.
    • object-jsonb: long key-value pairs > short key-value pairs. If the lengths are the same, compare each key-value pair in sequence, first the key and then the value.
CAUTION:

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

The JSONB type in row-store supports both B-tree and GIN indexes, while the JSONB type in column-store only supports CB-tree indexes.

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);
  • Create a B-tree index.
    1
    CREATE INDEX idx_test_data_age ON test USING btree(((data->>'age')::int));
    
    Use the B-tree index to query data where "age>1".
    1
    SELECT * FROM test WHERE (data->>'age')::int>1;
    
  • Create a GIN index.
    1
    CREATE INDEX idx_test_data ON test USING gin (data);
    
    Use the GIN index to check whether there are top-level keywords.
    1
    2
    SELECT * FROM test WHERE data ? 'id';
    SELECT * FROM test WHERE data ?| array['id','name'];
    
  • Use the GIN index to check whether there are non-top-level keywords.
    1
    2
    CREATE INDEX idx_test_data_nick_name ON test USING gin((data->'nick_name'));
    SELECT * FROM test WHERE data->'nick_name' ? 'Jacky';
    
  • Use @> to check whether JSON contains nested JSON objects.
    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.

  • Simple scalar/original values contain only the same value.
    1
    SELECT '"foo"'::jsonb @> '"foo"'::jsonb;
    
  • The array on the left contains the string on the right.
    1
    SELECT '[1, "aa", 3]'::jsonb ? 'aa';
    
  • The array on the left contains all elements of the array on the right. The sequence and repetition are not important.
    1
    SELECT '[1, 2, 3]'::jsonb @> '[1, 3, 1]'::jsonb;
    
  • The object-json on the left contains all key-values of the object-json on the right.
    1
    SELECT '{"product": "PostgreSQL", "version": 9.4, "jsonb":true}'::jsonb @> '{"version":9.4}'::jsonb;
    
  • The array on the left does not contain all elements in the array on the right, because the three elements in the array on the left are 1, 2, and [1,3], and the elements on the right are 1 and 3.
    1
    SELECT '[1, 2, [1, 3]]'::jsonb @> '[1, 3]'::jsonb; -- false
    
  • The array on the right does not contain all elements in the array on the left in the following example:
    1
    SELECT '{"foo": {"bar": "baz"}}'::jsonb @> '{"bar": "baz"}'::jsonb; -- false
    

Sitemizi ve deneyiminizi iyileştirmek için çerezleri kullanırız. Sitemizde tarama yapmaya devam ederek çerez politikamızı kabul etmiş olursunuz. Daha fazla bilgi edinin

Feedback

Feedback

Feedback

0/500

Selected Content

Submit selected content with the feedback