12.17.3 Functions That Search JSON Values (original) (raw)

12.17.3 Functions That Search JSON Values

The functions in this section perform search operations on JSON values to extract data from them, report whether data exists at a location within them, or report the path to data within them.

mysql> SET @j = '{"a": 1, "b": 2, "c": {"d": 4}}';  
mysql> SET @j2 = '1';  
mysql> SELECT JSON_CONTAINS(@j, @j2, '$.a');  
+-------------------------------+  
| JSON_CONTAINS(@j, @j2, '$.a') |  
+-------------------------------+  
|                             1 |  
+-------------------------------+  
mysql> SELECT JSON_CONTAINS(@j, @j2, '$.b');  
+-------------------------------+  
| JSON_CONTAINS(@j, @j2, '$.b') |  
+-------------------------------+  
|                             0 |  
+-------------------------------+  
mysql> SET @j2 = '{"d": 4}';  
mysql> SELECT JSON_CONTAINS(@j, @j2, '$.a');  
+-------------------------------+  
| JSON_CONTAINS(@j, @j2, '$.a') |  
+-------------------------------+  
|                             0 |  
+-------------------------------+  
mysql> SELECT JSON_CONTAINS(@j, @j2, '$.c');  
+-------------------------------+  
| JSON_CONTAINS(@j, @j2, '$.c') |  
+-------------------------------+  
|                             1 |  
+-------------------------------+  
mysql> SET @j = '{"a": 1, "b": 2, "c": {"d": 4}}';  
mysql> SELECT JSON_CONTAINS_PATH(@j, 'one', '$.a', '$.e');  
+---------------------------------------------+  
| JSON_CONTAINS_PATH(@j, 'one', '$.a', '$.e') |  
+---------------------------------------------+  
|                                           1 |  
+---------------------------------------------+  
mysql> SELECT JSON_CONTAINS_PATH(@j, 'all', '$.a', '$.e');  
+---------------------------------------------+  
| JSON_CONTAINS_PATH(@j, 'all', '$.a', '$.e') |  
+---------------------------------------------+  
|                                           0 |  
+---------------------------------------------+  
mysql> SELECT JSON_CONTAINS_PATH(@j, 'one', '$.c.d');  
+----------------------------------------+  
| JSON_CONTAINS_PATH(@j, 'one', '$.c.d') |  
+----------------------------------------+  
|                                      1 |  
+----------------------------------------+  
mysql> SELECT JSON_CONTAINS_PATH(@j, 'one', '$.a.d');  
+----------------------------------------+  
| JSON_CONTAINS_PATH(@j, 'one', '$.a.d') |  
+----------------------------------------+  
|                                      0 |  
+----------------------------------------+  
mysql> SELECT JSON_EXTRACT('[10, 20, [30, 40]]', '$[1]');  
+--------------------------------------------+  
| JSON_EXTRACT('[10, 20, [30, 40]]', '$[1]') |  
+--------------------------------------------+  
| 20                                         |  
+--------------------------------------------+  
mysql> SELECT JSON_EXTRACT('[10, 20, [30, 40]]', '$[1]', '$[0]');  
+----------------------------------------------------+  
| JSON_EXTRACT('[10, 20, [30, 40]]', '$[1]', '$[0]') |  
+----------------------------------------------------+  
| [20, 10]                                           |  
+----------------------------------------------------+  
mysql> SELECT JSON_EXTRACT('[10, 20, [30, 40]]', '$[2][*]');  
+-----------------------------------------------+  
| JSON_EXTRACT('[10, 20, [30, 40]]', '$[2][*]') |  
+-----------------------------------------------+  
| [30, 40]                                      |  
+-----------------------------------------------+  

MySQL 5.7.9 and later supports the-> operator as shorthand for this function as used with 2 arguments where the left hand side is aJSON column identifier (not an expression) and the right hand side is the JSON path to be matched within the column.

mysql> SELECT c, JSON_EXTRACT(c, "$.id"), g  
     > FROM jemp  
     > WHERE JSON_EXTRACT(c, "$.id") > 1  
     > ORDER BY JSON_EXTRACT(c, "$.name");  
+-------------------------------+-----------+------+  
| c                             | c->"$.id" | g    |  
+-------------------------------+-----------+------+  
| {"id": "3", "name": "Barney"} | "3"       |    3 |  
| {"id": "4", "name": "Betty"}  | "4"       |    4 |  
| {"id": "2", "name": "Wilma"}  | "2"       |    2 |  
+-------------------------------+-----------+------+  
3 rows in set (0.00 sec)  
mysql> SELECT c, c->"$.id", g  
     > FROM jemp  
     > WHERE c->"$.id" > 1  
     > ORDER BY c->"$.name";  
+-------------------------------+-----------+------+  
| c                             | c->"$.id" | g    |  
+-------------------------------+-----------+------+  
| {"id": "3", "name": "Barney"} | "3"       |    3 |  
| {"id": "4", "name": "Betty"}  | "4"       |    4 |  
| {"id": "2", "name": "Wilma"}  | "2"       |    2 |  
+-------------------------------+-----------+------+  
3 rows in set (0.00 sec)  

This functionality is not limited toSELECT, as shown here:

mysql> ALTER TABLE jemp ADD COLUMN n INT;  
Query OK, 0 rows affected (0.68 sec)  
Records: 0  Duplicates: 0  Warnings: 0  
mysql> UPDATE jemp SET n=1 WHERE c->"$.id" = "4";  
Query OK, 1 row affected (0.04 sec)  
Rows matched: 1  Changed: 1  Warnings: 0  
mysql> SELECT c, c->"$.id", g, n  
     > FROM jemp  
     > WHERE JSON_EXTRACT(c, "$.id") > 1  
     > ORDER BY c->"$.name";  
+-------------------------------+-----------+------+------+  
| c                             | c->"$.id" | g    | n    |  
+-------------------------------+-----------+------+------+  
| {"id": "3", "name": "Barney"} | "3"       |    3 | NULL |  
| {"id": "4", "name": "Betty"}  | "4"       |    4 |    1 |  
| {"id": "2", "name": "Wilma"}  | "2"       |    2 | NULL |  
+-------------------------------+-----------+------+------+  
3 rows in set (0.00 sec)  
mysql> DELETE FROM jemp WHERE c->"$.id" = "4";  
Query OK, 1 row affected (0.04 sec)  
mysql> SELECT c, c->"$.id", g, n  
     > FROM jemp  
     > WHERE JSON_EXTRACT(c, "$.id") > 1  
     > ORDER BY c->"$.name";  
+-------------------------------+-----------+------+------+  
| c                             | c->"$.id" | g    | n    |  
+-------------------------------+-----------+------+------+  
| {"id": "3", "name": "Barney"} | "3"       |    3 | NULL |  
| {"id": "2", "name": "Wilma"}  | "2"       |    2 | NULL |  
+-------------------------------+-----------+------+------+  
2 rows in set (0.00 sec)  

(See Indexing a Generated Column to Provide a JSON Column Index, for the statements used to create and populate the table just shown.)
This also works with JSON array values, as shown here:

mysql> CREATE TABLE tj10 (a JSON, b INT);  
Query OK, 0 rows affected (0.26 sec)  
mysql> INSERT INTO tj10  
     > VALUES ("[3,10,5,17,44]", 33), ("[3,10,5,17,[22,44,66]]", 0);  
Query OK, 1 row affected (0.04 sec)  
mysql> SELECT a->"$[4]" FROM tj10;  
+--------------+  
| a->"$[4]"    |  
+--------------+  
| 44           |  
| [22, 44, 66] |  
+--------------+  
2 rows in set (0.00 sec)  
mysql> SELECT * FROM tj10 WHERE a->"$[0]" = 3;  
+------------------------------+------+  
| a                            | b    |  
+------------------------------+------+  
| [3, 10, 5, 17, 44]           |   33 |  
| [3, 10, 5, 17, [22, 44, 66]] |    0 |  
+------------------------------+------+  
2 rows in set (0.00 sec)  

Nested arrays are supported. An expression using-> evaluates as NULL if no matching key is found in the target JSON document, as shown here:

mysql> SELECT * FROM tj10 WHERE a->"$[4][1]" IS NOT NULL;  
+------------------------------+------+  
| a                            | b    |  
+------------------------------+------+  
| [3, 10, 5, 17, [22, 44, 66]] |    0 |  
+------------------------------+------+  
mysql> SELECT a->"$[4][1]" FROM tj10;  
+--------------+  
| a->"$[4][1]" |  
+--------------+  
| NULL         |  
| 44           |  
+--------------+  
2 rows in set (0.00 sec)  

This is the same behavior as seen in such cases when usingJSON_EXTRACT():

mysql> SELECT JSON_EXTRACT(a, "$[4][1]") FROM tj10;  
+----------------------------+  
| JSON_EXTRACT(a, "$[4][1]") |  
+----------------------------+  
| NULL                       |  
| 44                         |  
+----------------------------+  
2 rows in set (0.00 sec)  
mysql> SELECT * FROM jemp WHERE g > 2;  
+-------------------------------+------+  
| c                             | g    |  
+-------------------------------+------+  
| {"id": "3", "name": "Barney"} |    3 |  
| {"id": "4", "name": "Betty"}  |    4 |  
+-------------------------------+------+  
2 rows in set (0.01 sec)  
mysql> SELECT c->'$.name' AS name  
    ->     FROM jemp WHERE g > 2;  
+----------+  
| name     |  
+----------+  
| "Barney" |  
| "Betty"  |  
+----------+  
2 rows in set (0.00 sec)  
mysql> SELECT JSON_UNQUOTE(c->'$.name') AS name  
    ->     FROM jemp WHERE g > 2;  
+--------+  
| name   |  
+--------+  
| Barney |  
| Betty  |  
+--------+  
2 rows in set (0.00 sec)  
mysql> SELECT c->>'$.name' AS name  
    ->     FROM jemp WHERE g > 2;  
+--------+  
| name   |  
+--------+  
| Barney |  
| Betty  |  
+--------+  
2 rows in set (0.00 sec)  

See Indexing a Generated Column to Provide a JSON Column Index, for the SQL statements used to create and populate thejemp table in the set of examples just shown.
This operator can also be used with JSON arrays, as shown here:

mysql> CREATE TABLE tj10 (a JSON, b INT);  
Query OK, 0 rows affected (0.26 sec)  
mysql> INSERT INTO tj10 VALUES  
    ->     ('[3,10,5,"x",44]', 33),  
    ->     ('[3,10,5,17,[22,"y",66]]', 0);  
Query OK, 2 rows affected (0.04 sec)  
Records: 2  Duplicates: 0  Warnings: 0  
mysql> SELECT a->"$[3]", a->"$[4][1]" FROM tj10;  
+-----------+--------------+  
| a->"$[3]" | a->"$[4][1]" |  
+-----------+--------------+  
| "x"       | NULL         |  
| 17        | "y"          |  
+-----------+--------------+  
2 rows in set (0.00 sec)  
mysql> SELECT a->>"$[3]", a->>"$[4][1]" FROM tj10;  
+------------+---------------+  
| a->>"$[3]" | a->>"$[4][1]" |  
+------------+---------------+  
| x          | NULL          |  
| 17         | y             |  
+------------+---------------+  
2 rows in set (0.00 sec)  

As with->, the ->> operator is always expanded in the output of EXPLAIN, as the following example demonstrates:

mysql> EXPLAIN SELECT c->>'$.name' AS name  
    ->     FROM jemp WHERE g > 2\G  
*************************** 1. row ***************************  
           id: 1  
  select_type: SIMPLE  
        table: jemp  
   partitions: NULL  
         type: range  
possible_keys: i  
          key: i  
      key_len: 5  
          ref: NULL  
         rows: 2  
     filtered: 100.00  
        Extra: Using where  
1 row in set, 1 warning (0.00 sec)  
mysql> SHOW WARNINGS\G  
*************************** 1. row ***************************  
  Level: Note  
   Code: 1003  
Message: /* select#1 */ select  
json_unquote(json_extract(`jtest`.`jemp`.`c`,'$.name')) AS `name` from  
`jtest`.`jemp` where (`jtest`.`jemp`.`g` > 2)  
1 row in set (0.00 sec)  

This is similar to how MySQL expands the-> operator in the same circumstances.
The ->> operator was added in MySQL 5.7.13.

mysql> SELECT JSON_KEYS('{"a": 1, "b": {"c": 30}}');  
+---------------------------------------+  
| JSON_KEYS('{"a": 1, "b": {"c": 30}}') |  
+---------------------------------------+  
| ["a", "b"]                            |  
+---------------------------------------+  
mysql> SELECT JSON_KEYS('{"a": 1, "b": {"c": 30}}', '$.b');  
+----------------------------------------------+  
| JSON_KEYS('{"a": 1, "b": {"c": 30}}', '$.b') |  
+----------------------------------------------+  
| ["c"]                                        |  
+----------------------------------------------+  
mysql> SET @j = '["abc", [{"k": "10"}, "def"], {"x":"abc"}, {"y":"bcd"}]';  
mysql> SELECT JSON_SEARCH(@j, 'one', 'abc');  
+-------------------------------+  
| JSON_SEARCH(@j, 'one', 'abc') |  
+-------------------------------+  
| "$[0]"                        |  
+-------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', 'abc');  
+-------------------------------+  
| JSON_SEARCH(@j, 'all', 'abc') |  
+-------------------------------+  
| ["$[0]", "$[2].x"]            |  
+-------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', 'ghi');  
+-------------------------------+  
| JSON_SEARCH(@j, 'all', 'ghi') |  
+-------------------------------+  
| NULL                          |  
+-------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '10');  
+------------------------------+  
| JSON_SEARCH(@j, 'all', '10') |  
+------------------------------+  
| "$[1][0].k"                  |  
+------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '10', NULL, '$');  
+-----------------------------------------+  
| JSON_SEARCH(@j, 'all', '10', NULL, '$') |  
+-----------------------------------------+  
| "$[1][0].k"                             |  
+-----------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '10', NULL, '$[*]');  
+--------------------------------------------+  
| JSON_SEARCH(@j, 'all', '10', NULL, '$[*]') |  
+--------------------------------------------+  
| "$[1][0].k"                                |  
+--------------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '10', NULL, '$**.k');  
+---------------------------------------------+  
| JSON_SEARCH(@j, 'all', '10', NULL, '$**.k') |  
+---------------------------------------------+  
| "$[1][0].k"                                 |  
+---------------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '10', NULL, '$[*][0].k');  
+-------------------------------------------------+  
| JSON_SEARCH(@j, 'all', '10', NULL, '$[*][0].k') |  
+-------------------------------------------------+  
| "$[1][0].k"                                     |  
+-------------------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '10', NULL, '$[1]');  
+--------------------------------------------+  
| JSON_SEARCH(@j, 'all', '10', NULL, '$[1]') |  
+--------------------------------------------+  
| "$[1][0].k"                                |  
+--------------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '10', NULL, '$[1][0]');  
+-----------------------------------------------+  
| JSON_SEARCH(@j, 'all', '10', NULL, '$[1][0]') |  
+-----------------------------------------------+  
| "$[1][0].k"                                   |  
+-----------------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', 'abc', NULL, '$[2]');  
+---------------------------------------------+  
| JSON_SEARCH(@j, 'all', 'abc', NULL, '$[2]') |  
+---------------------------------------------+  
| "$[2].x"                                    |  
+---------------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '%a%');  
+-------------------------------+  
| JSON_SEARCH(@j, 'all', '%a%') |  
+-------------------------------+  
| ["$[0]", "$[2].x"]            |  
+-------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '%b%');  
+-------------------------------+  
| JSON_SEARCH(@j, 'all', '%b%') |  
+-------------------------------+  
| ["$[0]", "$[2].x", "$[3].y"]  |  
+-------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '%b%', NULL, '$[0]');  
+---------------------------------------------+  
| JSON_SEARCH(@j, 'all', '%b%', NULL, '$[0]') |  
+---------------------------------------------+  
| "$[0]"                                      |  
+---------------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '%b%', NULL, '$[2]');  
+---------------------------------------------+  
| JSON_SEARCH(@j, 'all', '%b%', NULL, '$[2]') |  
+---------------------------------------------+  
| "$[2].x"                                    |  
+---------------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '%b%', NULL, '$[1]');  
+---------------------------------------------+  
| JSON_SEARCH(@j, 'all', '%b%', NULL, '$[1]') |  
+---------------------------------------------+  
| NULL                                        |  
+---------------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '%b%', '', '$[1]');  
+-------------------------------------------+  
| JSON_SEARCH(@j, 'all', '%b%', '', '$[1]') |  
+-------------------------------------------+  
| NULL                                      |  
+-------------------------------------------+  
mysql> SELECT JSON_SEARCH(@j, 'all', '%b%', '', '$[3]');  
+-------------------------------------------+  
| JSON_SEARCH(@j, 'all', '%b%', '', '$[3]') |  
+-------------------------------------------+  
| "$[3].y"                                  |  
+-------------------------------------------+  

For more information about the JSON path syntax supported by MySQL, including rules governing the wildcard operators* and **, seeJSON Path Syntax.