Important
You are viewing the documentation of TiDB v8.2 (DMR ). PingCAP does not provide bug fixes for v8.2. Any bugs will be fixed in future releases. For general purposes, please use the latest LTS version of the TiDB database.
JSON Functions You can use JSON functions to work with data in the JSON data type .
Functions that create JSON values Function Name Description JSON_ARRAY() Evaluates a (possibly empty) list of values and returns a JSON array containing those values JSON_OBJECT() Evaluates a (possibly empty) list of key-value pairs and returns a JSON object containing those pairs JSON_QUOTE() Returns a string as a JSON value with quotes
Functions that search JSON values Function Name Description JSON_CONTAINS() Indicates by returning 1 or 0 whether a given candidate JSON document is contained within a target JSON document JSON_CONTAINS_PATH() Returns 0 or 1 to indicate whether a JSON document contains data at a given path or paths JSON_EXTRACT() Returns data from a JSON document, selected from the parts of the document matched by the path
arguments -> Returns the value from a JSON column after the evaluating path; an alias for JSON_EXTRACT(doc, path_literal)
->> Returns the value from a JSON column after the evaluating path and unquoting the result; an alias for JSON_UNQUOTE(JSON_EXTRACT(doc, path_literal))
JSON_KEYS() Returns the keys from the top-level value of a JSON object as a JSON array, or, if a path argument is given, the top-level keys from the selected path JSON_SEARCH() Search a JSON document for one or all matches of a string MEMBER OF() If the passed value is an element of the JSON array, returns 1. Otherwise, returns 0. JSON_OVERLAPS() Indicates whether two JSON documents have overlapping part. If yes, returns 1. If not, returns 0.
Functions that modify JSON values Function Name Description JSON_APPEND() An alias to JSON_ARRAY_APPEND()
JSON_ARRAY_APPEND() Appends values to the end of the indicated arrays within a JSON document and returns the result JSON_ARRAY_INSERT() Insert values into the specified locations of a JSON document and returns the result JSON_INSERT() Inserts data into a JSON document and returns the result JSON_MERGE_PATCH() Merges two or more JSON documents, without preserving values of duplicate keys JSON_MERGE_PRESERVE() Merges two or more JSON documents by preserving all values JSON_MERGE() A deprecated alias for JSON_MERGE_PRESERVE()
JSON_REMOVE() Removes data from a JSON document and returns the result JSON_REPLACE() Replaces existing values in a JSON document and returns the result JSON_SET() Inserts or updates data in a JSON document and returns the result JSON_UNQUOTE() Unquotes a JSON value and returns the result as a string
Functions that return JSON value attributes Function Name Description JSON_DEPTH() Returns the maximum depth of a JSON document JSON_LENGTH() Returns the length of a JSON document, or, if a path argument is given, the length of the value within the path JSON_TYPE() Returns a string indicating the type of a JSON value JSON_VALID() Checks if a json_doc is valid JSON.
Utility functions Function Name Description JSON_PRETTY() Pretty formatting of a JSON document JSON_STORAGE_FREE() Returns how much storage space was freed in the binary representation of the JSON value after it was updated in place. JSON_STORAGE_SIZE() Returns an approximate size of bytes required to store the json value. As the size does not account for TiKV using compression, the output of this function is not strictly compatible with MySQL.
Aggregate functions Validation functions Function Name Description JSON_SCHEMA_VALID() Validates a JSON document against a schema to ensure data integrity and consistency.
JSONPath Many of JSON functions use JSONPath to select parts of a JSON document.
Symbol Description $
Document root .
Member selection []
Array selection *
Wildcard **
Path wildcard [<n> to <n>]
Array range selection
The subsequent content takes the following JSON document as an example to demonstrate how to use JSONPath:
{
"database" : {
"name" : "TiDB" ,
"features" : [
"distributed" ,
"scalable" ,
"relational" ,
"cloud native"
] ,
"license" : "Apache-2.0 license" ,
"versions" : [
{
"version" : "v8.1.0" ,
"type" : "lts" ,
"release_date" : "2024-05-24"
} ,
{
"version" : "v8.0.0" ,
"type" : "dmr" ,
"release_date" : "2024-03-29"
}
]
} ,
"migration_tool" : {
"name" : "TiDB Data Migration" ,
"features" : [
"MySQL compatible" ,
"Shard merging"
] ,
"license" : "Apache-2.0 license"
}
}
JSONPath Description Example with JSON_EXTRACT()
$
The root of the document Returns the full document $.database
The database
object Returns the full structure starting with "database"
. It does not include "migration_tool"
and the structure below that. $.database.name
The name of the database. "TiDB"
$.database.features
All database features ["distributed", "scalable", "relational", "cloud native"]
$.database.features[0]
The first database feature. "distributed"
$.database.features[2]
The third database feature. "relational"
$.database.versions[0].type
The type of the first database version. "lts"
$.database.versions[*].release_date
The release date for all versions. ["2024-05-24","2024-03-29"]
$.*.features
Two array's of features [["distributed", "scalable", "relational", "cloud native"], ["MySQL compatible", "Shard merging"]]
$**.version
All versions, with path wildcard ["v8.1.0","v8.0.0"]
$.database.features[0 to 2]
Range of database features from the first to the third. ["scalable","relational"]
For more information, see the IETF draft for JSONPath .
See also Unsupported functions JSON_SCHEMA_VALIDATION_REPORT()
JSON_TABLE()
JSON_VALUE()
For more information, see #14486 .
MySQL compatibility