1
0
mirror of https://github.com/MariaDB/server.git synced 2025-07-27 18:02:13 +03:00

MDEV-26182: Implement JSON_INTERSECT()

The idea is to have simple functions that the user can combine to produce
the exact result one wants, whether the user wants JSON object that has
common keys with another JSON object, or same key/value pair etc. So
making simpler function helps here.

We accomplish this by making three separate functions.
1) JSON_OBJECT_FILTER_KEYS(Obj, Arr_keys):
Put keys ( which are basically strings ) in hash, go over the object and
get key one by one. If the key is present in the hash,
add the key-value pair to result.

2) JSON_OBJECT_TO_ARRAY(Obj) : Create a string variable, Go over the json
object, and add each key value pair as an array into the result.

3) JSON_ARRAY_INTERSECT(arr1, arr2) :
Go over one of the json and add each item of the array
in hash (after normalizing each item). Go over the second array,
search the normalized item one by one in the hash. If item is found,
add it to the result.

Implementation Idea: Holyfoot ( Alexey Botchkov)
Author: tanruixiang and Rucha Deodhar
This commit is contained in:
tanruixiang
2022-06-16 15:05:35 +08:00
committed by Rucha Deodhar
parent 15a7b6c0b7
commit 49088c914b
5 changed files with 1009 additions and 1 deletions

View File

@ -3783,3 +3783,162 @@ FROM JSON_TABLE(
COLUMNS (k VARCHAR(20) PATH '$.key', v VARCHAR(20) PATH '$.value', id FOR ORDINALITY)) AS jt;
--echo # End of 11.2 test
--echo #
--echo # Beginning of 11.2 tests
--echo #
--echo # MDEV-26182: Implement json_array_intersect()
--echo #
--echo # JSON_ARRAY_INTERSECT()
--echo # Scalar as elements
SET @json1= '[1,2,3]';
SET @json2= '[1,2,3]';
SELECT json_array_intersect(@json1, @json2);
SET @json1= '[1,2,3]';
SET @json2= '[1,2,4]';
SELECT json_array_intersect(@json1, @json2);
SET @json1= '["abc","def","ghi"]';
SET @json2= '["xyz", "abc", "tuv"]';
SELECT json_array_intersect(@json1, @json2);
SET @obj1= '[true]';
SET @obj2= '[false, "true"]';
select json_array_intersect(@obj1, @obj2);
SET @obj1= '[true]';
SET @obj2= '[false, true]';
select json_array_intersect(@obj1, @obj2);
SET @obj1= '[null, true]';
SET @obj2= '[false, null]';
select json_array_intersect(@obj1, @obj2);
--echo # array as elements
SET @json1= '[6,6,6]';
SET @json2= '[[1,2,3],[4,5,6],[1,3,2]]';
SELECT json_array_intersect(@json1, @json2);
SET @json1= '[[1,2,3],[4,5,6],[1,3,2]]';
SET @json2= '[[1,2,3],[4,5,6],[1,3,2]]';
SELECT json_array_intersect(@json1, @json2);
SET @json1= '[[1,2,3],[4,5,6],[1,3,2]]';
SET @json2= '[[1,2,3],[4,5,6],[1,4,2]]';
SELECT json_array_intersect(@json1, @json2);
--echo # object as elements
SET @json1 = '[{"k1":"v1","k2":"v2"},{"k2":"v2"}]';
SET @json2 = '[{"kkey1":"vvalue1"},{"k2":"v2","k1":"v1"}]';
SELECT json_array_intersect(@json1, @json2);
SET @json1 = '[{"k1":"v1","k2":"v2"},{"k2":"v2","k1":"v1"}]';
SET @json2 = '[{"k1":"v1","k2":"v2"},{"k1":"v1","k2":"v2"}]';
SELECT json_array_intersect(@json1, @json2);
--echo # multi type elements
SET @obj1= '[1,2,3, "abc", "xyz", {"key1":"val1"}, {"key2":"val2"}, [1,2,3]]';
SET @obj2= '[3.0, 4, 5, "abc", {"key1":"val1"}, [3,2,1]]';
select json_array_intersect(@obj1, @obj2);
SET @obj1= '[1, 2, 3, "abc", "xyz", {"key1": {"key2" : [1,2,3] } }, [4,5,6] ]';
SET @obj2= '[3.0, 4, 5, "abc", {"key1": {"key2" : [3,2,1]} }, {"key1": {"key2" : [1,2,3] } }, [4,5,6], [6,5,4] ]';
select json_array_intersect(@obj1, @obj2);
--echo # Checking duplicates
SET @obj1= '[1, 2, 3, 3, 3.0, "abc", true, true, {"key1":"val1"}]';
SET @obj2= '[3.0, 3, 5, "abc", "abc", true, {"key2":"val2"}, {"key1":"val1"}, {"key1":"val2"}]';
select json_array_intersect(@obj1, @obj2);
--echo # Checking Syntax error for JSON_ARRAY_INTERSECT()
SET @obj1= '[1, 2, 3, 3, 3.0, "abc", true, true, {"key1":"val1" ]';
SET @obj2= '[3.0, 3, 5, "abc", "abc", true, {"key2":"val2"}, {"key1":"val1"}, {"key1":"val2"}]';
select json_array_intersect(@obj1, @obj2);
--echo # Checking incorrect type for input
SET @obj1= '{"key1": "val1"}';
SET @arr1= '[ 1, 2, 3 ]';
SET @num1= '2';
SET @str1= '"abc"';
SET @bool1= 'true';
select json_array_intersect(@obj1, @arr1);
select json_array_intersect(@arr1, @obj1);
select json_array_intersect(@arr1, @num1);
select json_array_intersect(@num1, @bool1);
--echo # JSON_OBJECT_FILTER_KEYS()
SET @obj1= '{ "a": 1, "b": 2, "c": 3}';
SET @obj2= '{"b" : 10, "c": 20, "d": 30}';
SELECT JSON_OBJECT_FILTER_KEYS (@obj1, json_array_intersect(json_keys(@obj1), json_keys(@obj2)));
SET @obj1= '{ "a": 1, "b": {"key1": {"key2":"val2"}}, "c": [1, 2, 3] }';
SET @obj2= '{"b" : 10, "c": 20, "d": 30}';
SELECT JSON_OBJECT_FILTER_KEYS (@obj1, json_array_intersect(json_keys(@obj1), json_keys(@obj2)));
SET @obj1= '{ "a": 1, "b": {"key1": {"key2":"val2"}}, "c": [1, 2, 3] }';
SET @arr2='["x", "y", "z"]';
SELECT JSON_OBJECT_FILTER_KEYS(@obj1, @arr2);
SET @obj1= '{ "a": 1, "b": {"key1": {"key2":"val2"}}, "c": [1, 2, 3] }';
SET @arr2='["key2", "key1", "b"]';
SELECT JSON_OBJECT_FILTER_KEYS(@obj1, @arr1);
--echo # Incorrect type in input returns NULL
SELECT JSON_OBJECT_FILTER_KEYS(@obj1, @obj1);
SELECT JSON_OBJECT_FILTER_KEYS(@arr1, @arr1);
SET @obj1= '{ "a": 1, "b": {"key1": {"key2":"val2"}}, "c": [1, 2, 3] }';
SET @scalar1='2';
SELECT JSON_OBJECT_FILTER_KEYS(@obj1, @scalar1);
--echo # Checking syntax error
SET @obj1= '{ "a": 1, "b": 2, "c": 3}';
SET @obj2= '{"b" : 10, "c": 20, "d" 30}';
SELECT JSON_OBJECT_FILTER_KEYS (@obj1, json_array_intersect(json_keys(@obj1), json_keys(@obj2)));
SET @obj1= '{ "a": 1, "b": {"key1": {"key2":"val2"}}, "c": [1, 2, 3] }';
SET @arr2= '[ "key2", "key1", "b" ';
SELECT JSON_OBJECT_FILTER_KEYS(@obj1, @arr1);
--echo # JSON_OBJECT_TO_ARRAY()
SET @obj1= '{ "a": [1, 2, 3], "b": { "key1":"val1", "key2": {"key3":"val3"} }, "c": 3, "d" : 1, "e": "xyz", "f": true, "g" : null}';
SELECT JSON_OBJECT_TO_ARRAY(@obj1);
SET @obj1= '{ "a": [1, 2, 3], "b": { "key1":"val1", "key2": [1, 2, 3] }, "c": 3, "d" : 1, "e": "xyz", "f": true, "g" : null}';
SELECT JSON_OBJECT_TO_ARRAY(@obj1);
--echo # Checking syntax error
SET @obj1= '{ "a": [1, 2, 3], "b": "key1": "val1", "key2": {"key3":"val3"} }, "c": 3, "d" : 1, "e": "xyz", "f": true, "g" : null}';
SELECT JSON_OBJECT_TO_ARRAY(@obj1);
--echo Checking incorrect type in argument
SET @arr1= '[1, 2, 3]';
SELECT JSON_OBJECT_TO_ARRAY(@arr1);
--echo #
--echo # End of 11.2 Test
--echo #