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

The functions in this section perform search or comparison 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. The MEMBER OF() operator is also documented herein.

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 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.

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> SELECT JSON_OVERLAPS("[1,3,5,7]", "[2,5,7]");  
+---------------------------------------+  
| JSON_OVERLAPS("[1,3,5,7]", "[2,5,7]") |  
+---------------------------------------+  
|                                     1 |  
+---------------------------------------+  
1 row in set (0.00 sec)  
mysql> SELECT JSON_OVERLAPS("[1,3,5,7]", "[2,6,7]");  
+---------------------------------------+  
| JSON_OVERLAPS("[1,3,5,7]", "[2,6,7]") |  
+---------------------------------------+  
|                                     1 |  
+---------------------------------------+  
1 row in set (0.00 sec)  
mysql> SELECT JSON_OVERLAPS("[1,3,5,7]", "[2,6,8]");  
+---------------------------------------+  
| JSON_OVERLAPS("[1,3,5,7]", "[2,6,8]") |  
+---------------------------------------+  
|                                     0 |  
+---------------------------------------+  
1 row in set (0.00 sec)  

Partial matches are treated as no match, as shown here:

mysql> SELECT JSON_OVERLAPS('[[1,2],[3,4],5]', '[1,[2,3],[4,5]]');  
+-----------------------------------------------------+  
| JSON_OVERLAPS('[[1,2],[3,4],5]', '[1,[2,3],[4,5]]') |  
+-----------------------------------------------------+  
|                                                   0 |  
+-----------------------------------------------------+  
1 row in set (0.00 sec)  

When comparing objects, the result is true if they have at least one key-value pair in common.

mysql> SELECT JSON_OVERLAPS('{"a":1,"b":10,"d":10}', '{"c":1,"e":10,"f":1,"d":10}');  
+-----------------------------------------------------------------------+  
| JSON_OVERLAPS('{"a":1,"b":10,"d":10}', '{"c":1,"e":10,"f":1,"d":10}') |  
+-----------------------------------------------------------------------+  
|                                                                     1 |  
+-----------------------------------------------------------------------+  
1 row in set (0.00 sec)  
mysql> SELECT JSON_OVERLAPS('{"a":1,"b":10,"d":10}', '{"a":5,"e":10,"f":1,"d":20}');  
+-----------------------------------------------------------------------+  
| JSON_OVERLAPS('{"a":1,"b":10,"d":10}', '{"a":5,"e":10,"f":1,"d":20}') |  
+-----------------------------------------------------------------------+  
|                                                                     0 |  
+-----------------------------------------------------------------------+  
1 row in set (0.00 sec)  

If two scalars are used as the arguments to the function,JSON_OVERLAPS() performs a simple test for equality:

mysql> SELECT JSON_OVERLAPS('5', '5');  
+-------------------------+  
| JSON_OVERLAPS('5', '5') |  
+-------------------------+  
|                       1 |  
+-------------------------+  
1 row in set (0.00 sec)  
mysql> SELECT JSON_OVERLAPS('5', '6');  
+-------------------------+  
| JSON_OVERLAPS('5', '6') |  
+-------------------------+  
|                       0 |  
+-------------------------+  
1 row in set (0.00 sec)  

When comparing a scalar with an array,JSON_OVERLAPS() attempts to treat the scalar as an array element. In this example, the second argument 6 is interpreted as[6], as shown here:

mysql> SELECT JSON_OVERLAPS('[4,5,6,7]', '6');  
+---------------------------------+  
| JSON_OVERLAPS('[4,5,6,7]', '6') |  
+---------------------------------+  
|                               1 |  
+---------------------------------+  
1 row in set (0.00 sec)  

The function does not perform type conversions:

mysql> SELECT JSON_OVERLAPS('[4,5,"6",7]', '6');  
+-----------------------------------+  
| JSON_OVERLAPS('[4,5,"6",7]', '6') |  
+-----------------------------------+  
|                                 0 |  
+-----------------------------------+  
1 row in set (0.00 sec)  
mysql> SELECT JSON_OVERLAPS('[4,5,6,7]', '"6"');  
+-----------------------------------+  
| JSON_OVERLAPS('[4,5,6,7]', '"6"') |  
+-----------------------------------+  
|                                 0 |  
+-----------------------------------+  
1 row in set (0.00 sec)  
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.

JSON_VALUE(json_doc, path [RETURNING type] [on_empty] [on_error])  
on_empty:  
    {NULL | ERROR | DEFAULT value} ON EMPTY  
on_error:  
    {NULL | ERROR | DEFAULT value} ON ERROR  

jsondoc is a valid JSON document. If this is NULL, the function returnsNULL.
path is a JSON path pointing to a location in the document. This must be a string literal value.
type is one of the following data types:

mysql> SELECT JSON_VALUE('{"fname": "Joe", "lname": "Palmer"}', '$.fname');  
+--------------------------------------------------------------+  
| JSON_VALUE('{"fname": "Joe", "lname": "Palmer"}', '$.fname') |  
+--------------------------------------------------------------+  
| Joe                                                          |  
+--------------------------------------------------------------+  
mysql> SELECT JSON_VALUE('{"item": "shoes", "price": "49.95"}', '$.price'  
    -> RETURNING DECIMAL(4,2)) AS price;  
+-------+  
| price |  
+-------+  
| 49.95 |  
+-------+  

Except in cases where JSON_VALUE() returnsNULL, the statement SELECT JSON_VALUE(_`jsondoc`_,_`path`_ RETURNING_`type`_) is equivalent to the following statement:

SELECT CAST(  
    JSON_UNQUOTE( JSON_EXTRACT(json_doc, path) )  
    AS type  
);  

JSON_VALUE() simplifies creating indexes on JSON columns by making it unnecessary in many cases to create a generated column and then an index on the generated column. You can do this when creating a table t1 that has a JSON column by creating an index on an expression that usesJSON_VALUE() operating on that column (with a path that matches a value in that column), as shown here:

CREATE TABLE t1(  
    j JSON,  
    INDEX i1 ( (JSON_VALUE(j, '$.id' RETURNING UNSIGNED)) )  
);  

The following EXPLAIN output shows that a query against t1 employing the index expression in the WHERE clause uses the index thus created:

mysql> EXPLAIN SELECT * FROM t1  
    ->     WHERE JSON_VALUE(j, '$.id' RETURNING UNSIGNED) = 123\G  
*************************** 1. row ***************************  
           id: 1  
  select_type: SIMPLE  
        table: t1  
   partitions: NULL  
         type: ref  
possible_keys: i1  
          key: i1  
      key_len: 9  
          ref: const  
         rows: 1  
     filtered: 100.00  
        Extra: NULL  

This achieves much the same effect as creating a tablet2 with an index on a generated column (seeIndexing a Generated Column to Provide a JSON Column Index), like this one:

CREATE TABLE t2 (  
    j JSON,  
    g INT GENERATED ALWAYS AS (j->"$.id"),  
    INDEX i1 (g)  
);  

The EXPLAIN output for a query against this table, referencing the generated column, shows that the index is used in the same way as for the previous query against table t1:

mysql> EXPLAIN SELECT * FROM t2 WHERE g  = 123\G  
*************************** 1. row ***************************  
           id: 1  
  select_type: SIMPLE  
        table: t2  
   partitions: NULL  
         type: ref  
possible_keys: i1  
          key: i1  
      key_len: 5  
          ref: const  
         rows: 1  
     filtered: 100.00  
        Extra: NULL  

For information about using indexes on generated columns for indirect indexing of JSON columns, see Indexing a Generated Column to Provide a JSON Column Index.

mysql> SELECT 17 MEMBER OF('[23, "abc", 17, "ab", 10]');  
+-------------------------------------------+  
| 17 MEMBER OF('[23, "abc", 17, "ab", 10]') |  
+-------------------------------------------+  
|                                         1 |  
+-------------------------------------------+  
1 row in set (0.00 sec)  
mysql> SELECT 'ab' MEMBER OF('[23, "abc", 17, "ab", 10]');  
+---------------------------------------------+  
| 'ab' MEMBER OF('[23, "abc", 17, "ab", 10]') |  
+---------------------------------------------+  
|                                           1 |  
+---------------------------------------------+  
1 row in set (0.00 sec)  

Partial matches of array element values do not match:

mysql> SELECT 7 MEMBER OF('[23, "abc", 17, "ab", 10]');  
+------------------------------------------+  
| 7 MEMBER OF('[23, "abc", 17, "ab", 10]') |  
+------------------------------------------+  
|                                        0 |  
+------------------------------------------+  
1 row in set (0.00 sec)  
mysql> SELECT 'a' MEMBER OF('[23, "abc", 17, "ab", 10]');  
+--------------------------------------------+  
| 'a' MEMBER OF('[23, "abc", 17, "ab", 10]') |  
+--------------------------------------------+  
|                                          0 |  
+--------------------------------------------+  
1 row in set (0.00 sec)  

Conversions to and from string types are not performed:

mysql> SELECT  
    -> 17 MEMBER OF('[23, "abc", "17", "ab", 10]'),  
    -> "17" MEMBER OF('[23, "abc", 17, "ab", 10]')\G  
*************************** 1. row ***************************  
17 MEMBER OF('[23, "abc", "17", "ab", 10]'): 0  
"17" MEMBER OF('[23, "abc", 17, "ab", 10]'): 0  
1 row in set (0.00 sec)  

To use this operator with a value which is itself an array, it is necessary to cast it explicitly as a JSON array. You can do this with CAST(... AS JSON):

mysql> SELECT CAST('[4,5]' AS JSON) MEMBER OF('[[3,4],[4,5]]');  
+--------------------------------------------------+  
| CAST('[4,5]' AS JSON) MEMBER OF('[[3,4],[4,5]]') |  
+--------------------------------------------------+  
|                                                1 |  
+--------------------------------------------------+  
1 row in set (0.00 sec)  

It is also possible to perform the necessary cast using theJSON_ARRAY() function, like this:

mysql> SELECT JSON_ARRAY(4,5) MEMBER OF('[[3,4],[4,5]]');  
+--------------------------------------------+  
| JSON_ARRAY(4,5) MEMBER OF('[[3,4],[4,5]]') |  
+--------------------------------------------+  
|                                          1 |  
+--------------------------------------------+  
1 row in set (0.00 sec)  

Any JSON objects used as values to be tested or which appear in the target array must be coerced to the correct type usingCAST(... AS JSON) orJSON_OBJECT(). In addition, a target array containing JSON objects must itself be cast usingJSON_ARRAY. This is demonstrated in the following sequence of statements:

mysql> SET @a = CAST('{"a":1}' AS JSON);  
Query OK, 0 rows affected (0.00 sec)  
mysql> SET @b = JSON_OBJECT("b", 2);  
Query OK, 0 rows affected (0.00 sec)  
mysql> SET @c = JSON_ARRAY(17, @b, "abc", @a, 23);  
Query OK, 0 rows affected (0.00 sec)  
mysql> SELECT @a MEMBER OF(@c), @b MEMBER OF(@c);  
+------------------+------------------+  
| @a MEMBER OF(@c) | @b MEMBER OF(@c) |  
+------------------+------------------+  
|                1 |                1 |  
+------------------+------------------+  
1 row in set (0.00 sec)