JSON_ MATCH_ ANY
On this page
Checks for the existence of data within a JSON document that matches specified filter conditions.
Syntax
Longhand Syntax
-
The
JSON_
function returns true if there exists a value in the JSON at the filter path for which the filter predicate evaluates to true.MATCH_ ANY The filter predicate and filter path are described in Arguments. JSON_MATCH_ANY(<filter_predicate>, <json>, <filter_path>) -
The
JSON_
function returns true if there is a value (possibly null) in the JSON at the filter path.MATCH_ ANY_ EXISTS JSON_MATCH_ANY_EXISTS(<json>, <filter_path>)
Shorthand Syntax
-
filter_
is the same as in the longhand syntax.predicate -
filter_
is a dot-separated list of keys (as opposed to a comma-separated list of arguments in the longhand syntax).path -
::?
indicates the following period-separated values are array/object neutral.For example, each key can either be a direct field of a JSON object or a field of a JSON object within an array. -
EXISTS
: As the optional<filter_
is omitted in thepredicate> EXISTS
function, the syntax and behavior of theEXISTS
function is identical whether using either the shorthand or longhand syntax.JSON_MATCH_ANY(<json>::?<filter_path>[, <filter_predicate>])
Arguments
-
json
: the name of a JSON column or a JSON value. -
filter_
: a path specification.path -
Longhand syntax: a comma-separated list of dictionary keys or zero-indexed array positions.
-
Shorthand syntax: a period-separated list of dictionary keys or zero-indexed array positions.
-
-
filter_
: an optional predicate expression which is applied to every value matching the filter path.predicate Consists of special built-in functions.
Filter Path
-
The
filter_
, which is a set of keys or zero-indexed array positions, is used to recursively extract a JSON value or an element of a JSON array from thepath json
argument. -
If no
filter_
is provided, true is returned if the filter path exists.predicate -
The
filter_
is evaluated recursively against the JSON in thepath json
column using the following rules.-
If the current element identified by the
filter_
is an object, the next key in thepath filter_
is matched against the keys in the object.path -
If the current element identified by the
filter_
is an array, the next key in thepath filter_
is either matched as a zero-indexed position in the array or against the keys of any object that is an element of the array.path If both a zero-indexed array match or a key match are possible, the zero-indexed array match will be used. -
It is possible that there are several values in a
json
value which match thefilter_
.path In this case, the filter_
is applied on all values.predicate The function returns true if the predicate evalutates to true on one of the values.
-
Filter Predicate
-
The
filter_
is an optional predicate expression which is applied to every value matching thepredicate filter_
.path -
Several special built-in functions are used for the
filter_
.predicate The built-in functions that can be used in the filter_
include:predicate -
MATCH_
functions, as described below.PARAM_ <type>_ STRICT -
MATCH_
is used for all valid JSON types including true, false, JSON objects, and JSON arrays.PARAM_ JSON() There is intentionally no STRICT here.
-
The
filter_
is evaluated by running the specified built-in function on the value identified by thepredicate filter_
.path If the value at the filter_
does not match thepath <type>
, the built-in evaluates asSQL-NULL
. -
MATCH_
will evaluate as aPARAM_ <type>_ STRICT() SQL-NULL
if there is not a match to<type>
as defined below:-
MATCH_
matches only numeric JSON values (integers/floating point).PARAM_ BIGINT_ STRICT() Rounds to the nearest integer. -
MATCH_
matches only JSON booleans (true/false).PARAM_ BOOL_ STRICT() -
MATCH_
matches all numeric types (integers/floats).PARAM_ DOUBLE_ STRICT() Unlike JSON_
, it will not convert non-numeric types (booleans, strings, JSON objects, and JSON arrays) to double values.EXTRACT_ DOUBLE() -
MATCH_
matches only JSON strings.PARAM_ STRING_ STRICT() Unlike JSON_
it will not convert non-string types (not enclosed by quotes).EXTRACT_ STRING() Behaves the same as JSON_
with regards to theEXTRACT_ STRING() json_
global variable.extract_ string_ collation
-
-
MATCH_
when added to theELEMENTS JSON_
function, matches only the array elements themselves, not the entire array.MATCH_ ANY
Return Type
-
Return type is
TINYINT
. -
Returns 1 or 0 to indicate true or false.
Return Value
-
If a
filter_
is provided, returns 1 if the predicate evaulates to true for any value found at thepredicate filter_
.path -
If a
filter_
is not provided, returns 1 if thepredicate filter_
exists in the JSON.path -
Returns 0 otherwise.
MATCH_ ELEMENTS
The MATCH_
keyword reduces search time in JSON_
.filter_
, the filter_
is first tested against the entire array, and then, if that test fails, the filter_
is tested against each individual element of the array.MATCH_
, the filter_
is tested only against the array elements themselves.
For example, given the following JSON document and the following JSON_
query:
{“names”: [“Alex”, “Brad”, “Charlie”]}
JSON_MATCH_ANY(json_col::?names,MATCH_PARAM_STRING_STRICT() = “Brad”)
Without MATCH_
, the filter_MATCH_
, is first tested on the entire array, [“Alex”, “Brad”, “Charlie”]
, on which it evaluates to false.filter_
is tested on each individual element of the array (first ”Alex”, then ”Brad”, and then ”Charlie”); the filter_
evaluates to true on ”Brad”.
In certain cases, as in the above example, it does not make sense to test the filter_
on the entire array.MATCH_
keyword allows this costly first step to be skipped.filter_
on the entire JSON array as a whole, MATCH_
evaluates the predicate on each individual element of the array.
To use MATCH_
, add the MATCH_
keyword after the filter_
.MATCH_
.
MATCH_
is applied to the last key in the filter_
and requires that all matches using the last key are within an array.
Adding MATCH_
to the query above, the new query is as follows.
JSON_MATCH_ANY(MATCH_PARAM_STRING_STRICT() = "Brad", json_col, "names" MATCH_ELEMENTS)
The new query in shorthand syntax is as follows:
JSON_MATCH_ANY(json_col::?names*, MATCH_PARAM_STRING_STRICT() = "Brad")
If the value at the end of the keypath is not an array, MATCH_
prevents JSON_
from testing the filter_{“names”: “Brad”}
evaluates as false using the above JSON_
query with MATCH_
.
Examples
The examples in this section use the the table and values shown below:
CREATE TABLE json_exp(id int, json_row JSON);INSERT INTO json_exp VALUES(1, '{"alpha": {"beta": 6}}'),(2, '{"alpha": {"beta": 4}}'),(3, '{"alpha": [{"beta": 3}, {"beta": 8}, {"gamma": 2}, {"beta": 6}]}'),(4, '{"alpha": {"beta": [1,2,3,4,5,6]}}'),(5, '{"alpha": 1, "beta": 1}'),(6, '{"alpha": {"beta": null}}'),(7, '{"alpha": {"beta": true}}'),(8, '{"alpha": {"beta": "6"}}'),(9, '{"alpha": ["zeta", "zeta", {"1": {"beta": 8}}]}');
SELECT *FROM json_expORDER BY id;
+---------------------------------------------------------------+
|id | json_row |
+----+----------------------------------------------------------+
| 1 | {"alpha":{"beta":6}} |
| 2 | {"alpha":{"beta":4}} |
| 3 | {"alpha":[{"beta":3},{"beta":8},{"gamma":2},{"beta":6}]} |
| 4 | {"alpha":{"beta":[1,2,3,4,5,6]}} |
| 5 | {"alpha":1,"beta":1} |
| 6 | {"alpha":{"beta":null}} |
| 7 | {"alpha":{"beta":true}} |
| 8 | {"alpha":{"beta":"6"}} |
| 9 | {"alpha":["zeta","zeta",{"1":{"beta":8}}]} |
+----+----------------------------------------------------------+
Example 1 - JSON_ MATCH_ ANY_ EXISTS
Use the JSON_
function to find rows that contain the path alpha.
('alpha,'beta'
in longhand).ORDER BY
clause and is included to ensure consistent results.
Longhand Syntax:
SELECT id, json_rowFROM json_expWHERE JSON_MATCH_ANY_EXISTS(json_row, 'alpha', 'beta')ORDER BY id;
Shorthand Syntax:
SELECT id, json_rowFROM json_expWHERE JSON_MATCH_ANY(json_row::?alpha.beta)ORDER BY id;
Both versions of the query produce the following result.
+---------------------------------------------------------------+
|id | json_row |
+----+----------------------------------------------------------+
| 1 | {"alpha":{"beta":6}} |
| 2 | {"alpha":{"beta":4}} |
| 3 | {"alpha":[{"beta":3},{"beta":8},{"gamma":2},{"beta":6}]} |
| 4 | {"alpha":{"beta":[1,2,3,4,5,6]}} |
| 6 | {"alpha":{"beta":null}} |
| 7 | {"alpha":{"beta":true}} |
| 8 | {"alpha":{"beta":"6"}} |
+----+----------------------------------------------------------+
The JSON_
function returns true for the row with id 3, {"alpha”: [{"beta”: 3}, {"beta”: 1}, {“gamma: 2}, {"beta”: 6}]}
, because beta
is matched to a key of an object that is an element in the array.
The row with id 6, {"alpha":{"beta":null}}
, is included in the result because the path alpha.
('alpha','beta'
in longhand) exists in the JSON in that row, the fact that the value at that path is null does not prevent the row from being included in the result.
Example 2 - MATCH_ PARAM_ DOUBLE_ STRICT
Consider the following query that uses MATCH_
to looks for the value 6
at the path alpha.
('alpha','beta'
in longhand).
Longhand Syntax:
SELECT id, json_rowFROM json_expWHERE JSON_MATCH_ANY(MATCH_PARAM_DOUBLE_STRICT() = 6, json_row, 'alpha', 'beta')ORDER BY id;
Shorthand Syntax:
SELECT id, json_rowFROM json_expWHERE JSON_MATCH_ANY(json_row::?alpha.beta, MATCH_PARAM_DOUBLE_STRICT() = 6)ORDER BY id;
Both versions of the query produce the following result.
+---------------------------------------------------------------+
|id | json_row |
+----+----------------------------------------------------------+
| 1 | {"alpha":{"beta":6}} |
| 3 | {"alpha":[{"beta":3},{"beta":8},{"gamma":2},{"beta":6}]} |
| 4 | {"alpha":{"beta":[1,2,3,4,5,6]}} |
+----+----------------------------------------------------------+
For the row with id 3, {"alpha”: [{"beta”: 3}, {"beta”: 1}, {“gamma”: 2}, {"beta”: 6}]}
, the filter_
matches to the objects with values 3
, 1
, and 6
and the filter_
is evaluated on those values.6
evaluates to true, and the row is included in the result.
For the row with id 4, {"alpha”: {"beta”: [1,2,3,4,5,6]}}
, the filter_
is evaluated on all values in the array.6
evaluates to true, and the row is included in the result.
For the row with id 8, {"alpha”: {"beta”: "6"}}
, the filter_
is evaluated on the JSON string value "6"
, which causes MATCH_
to evaluate to SQL-NULL
(distinct from JSON null) because of mismatching types.JSON_
works.
Example 3 - MATCH_ PARAM_ JSON
Use the MATCH_
function to identify null values at the path alpha.
('alpha','beta'
in longhand).MATCH_
extracts null as JSON null.
Longhand Syntax:
SELECT id, json_rowFROM json_expWHERE JSON_MATCH_ANY(MATCH_PARAM_JSON() = 'null', json_row, 'alpha', 'beta');
Shorthand Syntax:
SELECT id, json_rowFROM json_expWHERE JSON_MATCH_ANY(json_row::?alpha.beta, MATCH_PARAM_JSON() = 'null');
Both versions of the query produce the following result.
+---------------------------------------------------------------+
|id | json_row |
+----+----------------------------------------------------------+
| 6 | {"alpha":{"beta":null}} |
+----+----------------------------------------------------------+
Example 4 - MATCH_ PARAM_ BIGINT_ STRICT
Use the MATCH_
function to extract numeric values at the path alpha.
('alpha','1', 'beta'
) that round to 1
.
Longhand Syntax:
SELECT id, json_rowFROM json_expWHERE JSON_MATCH_ANY(MATCH_PARAM_BIGINT_STRICT() = 8, json_row, 'alpha', 1, 'beta');
Shorthand Syntax:
SELECT id, json_rowFROM json_expWHERE JSON_MATCH_ANY(json_row::?alpha.`1`.beta, MATCH_PARAM_BIGINT_STRICT() = 8);
Both versions of the query produce the following result.
+---------------------------------------------------------------+
|id | json_row |
+----+----------------------------------------------------------+
| 3 | {"alpha":[{"beta":3},{"beta":8},{"gamma":2},{"beta":6}]} |
+----+----------------------------------------------------------+
If a key in the filter_
can either index the array or match a key in an object in the array, JSON_
will match the key as a zero-indexed array position.{"alpha": ["zeta", "zeta", {"1": {"beta": 8}}]}
, does not match because the key 1
in the filter_
( alpha.
) can index the array but the value at index 1
is "zeta"
, which is not equal to 8
and fails the filter_
test.
Example 5 - MATCH ELEMENTS
Use the MATCH_
keyword to test a predicate directly against all elements in an array without first testing against the whole array.
Create a purchase_
table with a column, purchases
of type JSON, and insert the following data into this table.
CREATE TABLE purchase_info(p JSON);INSERT INTO purchase_info VALUES('{"purchase": {"items": [1,2,3], "name": "John"}, "order_id": 101}'),('{"purchase": {"items": 1, "name": "Dave"}, "order_id": 102}'),('{"purchase": {"items": [1], "name": "Ann"}, "order_id": 103}'),('{"purchase": {"items": [2,3,4], "name": "Brian"}, "order_id": 104}');
The first of the following two queries looks for purchases where item 1
was ordered.1
either in the array of items (order 101) or in the value of items (order 102).
However, in many cases, the desired behavior is to search only the elements of the array.MATCH_
after the purchase.
filter_
to specify that only the elements of the array should be searched.
-- without MATCH_ELEMENTSSELECTp::%order_id AS order_id,JSON_MATCH_ANY(p::?purchase.items, MATCH_PARAM_BIGINT_STRICT() = 1) AS ordered_item_oneFROM purchase_infoORDER BY order_id;-- with MATCH_ELEMENTSSELECTp::%order_id AS order_id,JSON_MATCH_ANY(MATCH_PARAM_BIGINT_STRICT() = 1, p, "purchase", "items" MATCH_ELEMENTS) AS ordered_item_one_in_arrayFROM purchase_infoORDER BY order_id;
The result of the first SELECT query (without MATCH_
) is shown below.filter_
because 1
is in the value of items in order 102 and in the array of items in order 101 and 103.
+----------+------------------+| order_id | ordered_item_one |+----------+------------------+| 101 | 1 || 102 | 1 || 103 | 1 || 104 | 0 |+----------+------------------+
The result of the second SELECT query (with *
to indicate MATCH_
) only orders 101 and 103 match the filter_
and the query is more efficient as the system skips matching the value of the items array iteslf.
+----------+---------------------------+| order_id | ordered_item_one_in_array |+----------+---------------------------+| 101 | 1 || 102 | 0 || 103 | 1 || 104 | 0 |+----------+---------------------------+
The second query expressed with shorthand syntax is as follows:
SELECTp::%order_id AS order_id,JSON_MATCH_ANY(p::?purchase.items*, MATCH_PARAM_BIGINT_STRICT() = 1) AS ordered_item_one_in_arrayFROM purchase_info;
Example 6 - Match Multiple Paths
With JSON_
, it is possible to match multiple paths in a single JSON value.
Create a restaurants
table with a column of type JSON which will contain information about restaurants.
Each row added to the table is a JSON array and each row represents information about restaurants for a particular city.
CREATE TABLE restaurants_json (restaurantinfo JSON);INSERT INTO restaurants_json VALUES('[{"city":"Paris","type":"Bakery","name":"La Boulangerie"},{"city":"Paris","type":"Pizzeria","name":"Pizza Pizza"}]'),('[{"city":"Rome","type":"Bakery","name":"La Panetteria"},{"city":"Rome","type":"Pizzeria","name":"Roma Pizza"}]');
It is possible to query the JSON arrays in the restaurantinfo
column to match on both the type
and name
of the restaurant.
The query below searches for restaurant information for cities that have a bakery named La Boulangerie
.La Boulangerie
in Paris.
SELECT *FROM restaurants_jsonWHEREJSON_MATCH_ANY(JSON_EXTRACT_STRING(MATCH_PARAM_JSON(),'type') = 'Bakery'AND JSON_EXTRACT_STRING(MATCH_PARAM_JSON(),'name') = 'La Boulangerie',restaurantinfo MATCH_ELEMENTS);
+------------------------------------------------------------------------------------------------------------------+
| restaurantinfo |
+------------------------------------------------------------------------------------------------------------------+
| [{"city":"Paris","name":"La Boulangerie","type":"Bakery"},{"city":"Paris","name":"Pizza Pizza","type":"Pizzeria"}] |
+------------------------------------------------------------------------------------------------------------------+
The query below looks for restaurant information for cities that have a bakery named Pizza Pizza
.
SELECT *FROM restaurants_jsonWHEREJSON_MATCH_ANY(JSON_EXTRACT_STRING(MATCH_PARAM_JSON(), 'type') = 'Bakery'AND JSON_EXTRACT_STRING(MATCH_PARAM_JSON(), 'name') = 'Pizza Pizza',restaurantinfo MATCH_ELEMENTS);
Empty set (0.02 sec)
A query, such as the above two queries, which use a predicate (WHERE
clause) that contains JSON_
with a nested JSON_
over MATCH_
will result in a more efficient query.type
and name
are decoded, which reduces the amount of data that is read and processed.
Columnstore Optimization
JSON_
is only optimized over columnstore if <filter_
-
MATCH_
functions.PARAM_ <type>() -
Constant literals: strings, integers, floating point numbers, booleans, and NULL.
-
Comparison operators: =, !=, <, <=, >, >=, <=>, IS, IN, and BETWEEN.
-
Logical operators: AND, OR, and NOT.
-
Typecasts: implicit and explicit.
Last modified: October 4, 2024