Skip to content

Commit 593885f

Browse files
erichermancvicentiu
andcommitted
MDEV-23143 Add JSON_EQUALS function
This patch implements JSON_EQUALS SQL function. The function takes advantage of the json_normalize functionality and does the following: norm_a = json_normalize(a) norm_b = json_normalize(b) return strcmp(norm_a, norm_b) Co-authored-by: Vicențiu Ciorbaru <vicentiu@mariadb.org>
1 parent fcde341 commit 593885f

File tree

5 files changed

+268
-0
lines changed

5 files changed

+268
-0
lines changed

mysql-test/main/json_equals.result

Lines changed: 98 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,98 @@
1+
select json_equals("{}", "{}");
2+
json_equals("{}", "{}")
3+
1
4+
select json_equals("{}", "[]");
5+
json_equals("{}", "[]")
6+
0
7+
select json_equals("{}", NULL);
8+
json_equals("{}", NULL)
9+
NULL
10+
select json_equals("", "");
11+
json_equals("", "")
12+
NULL
13+
select json_equals("", 1);
14+
json_equals("", 1)
15+
NULL
16+
select json_equals(now(), now());
17+
json_equals(now(), now())
18+
NULL
19+
select json_equals('{"a":[1, 2, 3]}', '{"a":[1, 2, 3, 4]}');
20+
json_equals('{"a":[1, 2, 3]}', '{"a":[1, 2, 3, 4]}')
21+
0
22+
select json_equals('{"a":[1, 2, 3]}', '{"a":[1, 2, 3]}');
23+
json_equals('{"a":[1, 2, 3]}', '{"a":[1, 2, 3]}')
24+
1
25+
select json_equals('{"țanțoș":[1, 2, "ț", {"some uâ߀":"uâßr"}]}',
26+
'{"țanțoș":[1, 2, "ț", {"some uâ߀":"uâßr"}]}');
27+
json_equals('{"țanțoș":[1, 2, "ț", {"some uâ߀":"uâßr"}]}',
28+
'{"țanțoș":[1, 2, "ț", {"some uâ߀":"uâßr"}]}')
29+
1
30+
select json_equals('{"a" : [0.123456789123456789], "b" : [1, 2, 3]}',
31+
'{"b" : [1, 2, 3], "a" : [0.123456789123456789]}');
32+
json_equals('{"a" : [0.123456789123456789], "b" : [1, 2, 3]}',
33+
'{"b" : [1, 2, 3], "a" : [0.123456789123456789]}')
34+
1
35+
#
36+
# Test max json depth for json_equals.
37+
#
38+
with recursive rec_json (step, obj) as (
39+
select 1, cast('{"key":"value"}' as varchar(1000))
40+
union
41+
select r.step + 1, JSON_INSERT('{}', '$.obj', JSON_QUERY(r.obj, '$'))
42+
from rec_json r
43+
where r.step < 10
44+
)
45+
select step, obj, json_equals(obj, obj) from rec_json;
46+
step obj json_equals(obj, obj)
47+
1 {"key":"value"} 1
48+
2 {"obj": {"key": "value"}} 1
49+
3 {"obj": {"obj": {"key": "value"}}} 1
50+
4 {"obj": {"obj": {"obj": {"key": "value"}}}} 1
51+
5 {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}} 1
52+
6 {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}} 1
53+
7 {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}} 1
54+
8 {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}} 1
55+
9 {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}}} 1
56+
10 {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}}}} 1
57+
#
58+
# 31 levels of nesting.
59+
#
60+
select json_equals('{"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}',
61+
'{"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}') as 31_levels;
62+
31_levels
63+
1
64+
#
65+
# 32 Levels of nesting. This should hit max json depth.
66+
#
67+
select json_equals('{"obj":{"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}',
68+
'{"obj":{"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}') as 32_levels;
69+
32_levels
70+
NULL
71+
#
72+
# test values from different charset
73+
# (UTF-8 two-bytes vs. latin1 single high-byte)
74+
#
75+
create table t1 (a varchar(200) character set latin1);
76+
create table t2 (a varchar(200) character set utf8);
77+
insert into t1 values (UNHEX('22CA22'));
78+
set names utf8;
79+
insert into t2 values (UNHEX('22C38A22'));
80+
select a from t1;
81+
a
82+
"Ê"
83+
select hex(a) from t1;
84+
hex(a)
85+
22CA22
86+
select a from t2;
87+
a
88+
"Ê"
89+
select hex(a) from t2;
90+
hex(a)
91+
22C38A22
92+
select t1.a, t2.a, t1.a = t2.a,
93+
json_valid(t1.a), json_valid(t2.a), json_equals(t1.a, t2.a)
94+
from t1, t2;
95+
a a t1.a = t2.a json_valid(t1.a) json_valid(t2.a) json_equals(t1.a, t2.a)
96+
"Ê" "Ê" 1 1 1 1
97+
drop table t1;
98+
drop table t2;

mysql-test/main/json_equals.test

Lines changed: 69 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,69 @@
1+
2+
select json_equals("{}", "{}");
3+
4+
select json_equals("{}", "[]");
5+
6+
select json_equals("{}", NULL);
7+
8+
select json_equals("", "");
9+
10+
select json_equals("", 1);
11+
12+
select json_equals(now(), now());
13+
14+
select json_equals('{"a":[1, 2, 3]}', '{"a":[1, 2, 3, 4]}');
15+
16+
select json_equals('{"a":[1, 2, 3]}', '{"a":[1, 2, 3]}');
17+
18+
select json_equals('{"țanțoș":[1, 2, "ț", {"some uâ߀":"uâßr"}]}',
19+
'{"țanțoș":[1, 2, "ț", {"some uâ߀":"uâßr"}]}');
20+
21+
select json_equals('{"a" : [0.123456789123456789], "b" : [1, 2, 3]}',
22+
'{"b" : [1, 2, 3], "a" : [0.123456789123456789]}');
23+
24+
--echo #
25+
--echo # Test max json depth for json_equals.
26+
--echo #
27+
with recursive rec_json (step, obj) as (
28+
select 1, cast('{"key":"value"}' as varchar(1000))
29+
union
30+
select r.step + 1, JSON_INSERT('{}', '$.obj', JSON_QUERY(r.obj, '$'))
31+
from rec_json r
32+
where r.step < 10
33+
)
34+
select step, obj, json_equals(obj, obj) from rec_json;
35+
36+
--echo #
37+
--echo # 31 levels of nesting.
38+
--echo #
39+
select json_equals('{"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}',
40+
'{"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}') as 31_levels;
41+
42+
--echo #
43+
--echo # 32 Levels of nesting. This should hit max json depth.
44+
--echo #
45+
select json_equals('{"obj":{"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}',
46+
'{"obj":{"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"obj": {"key": "value"}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}}') as 32_levels;
47+
48+
49+
--echo #
50+
--echo # test values from different charset
51+
--echo # (UTF-8 two-bytes vs. latin1 single high-byte)
52+
--echo #
53+
create table t1 (a varchar(200) character set latin1);
54+
create table t2 (a varchar(200) character set utf8);
55+
insert into t1 values (UNHEX('22CA22'));
56+
set names utf8;
57+
insert into t2 values (UNHEX('22C38A22'));
58+
59+
select a from t1;
60+
select hex(a) from t1;
61+
select a from t2;
62+
select hex(a) from t2;
63+
64+
select t1.a, t2.a, t1.a = t2.a,
65+
json_valid(t1.a), json_valid(t2.a), json_equals(t1.a, t2.a)
66+
from t1, t2;
67+
68+
drop table t1;
69+
drop table t2;

sql/item_create.cc

Lines changed: 24 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -915,6 +915,19 @@ class Create_func_json_normalize : public Create_func_arg1
915915
};
916916

917917

918+
class Create_func_json_equals : public Create_func_arg2
919+
{
920+
public:
921+
virtual Item *create_2_arg(THD *thd, Item *arg1, Item *arg2);
922+
923+
static Create_func_json_equals s_singleton;
924+
925+
protected:
926+
Create_func_json_equals() {}
927+
virtual ~Create_func_json_equals() {}
928+
};
929+
930+
918931
class Create_func_json_exists : public Create_func_arg2
919932
{
920933
public:
@@ -3619,6 +3632,16 @@ Create_func_json_normalize::create_1_arg(THD *thd, Item *arg1)
36193632
}
36203633

36213634

3635+
Create_func_json_equals Create_func_json_equals::s_singleton;
3636+
3637+
Item*
3638+
Create_func_json_equals::create_2_arg(THD *thd, Item *arg1, Item *arg2)
3639+
{
3640+
status_var_increment(thd->status_var.feature_json);
3641+
return new (thd->mem_root) Item_func_json_equals(thd, arg1, arg2);
3642+
}
3643+
3644+
36223645
Create_func_json_exists Create_func_json_exists::s_singleton;
36233646

36243647
Item*
@@ -5574,6 +5597,7 @@ Native_func_registry func_array[] =
55745597
{ { STRING_WITH_LEN("JSON_CONTAINS_PATH") }, BUILDER(Create_func_json_contains_path)},
55755598
{ { STRING_WITH_LEN("JSON_DEPTH") }, BUILDER(Create_func_json_depth)},
55765599
{ { STRING_WITH_LEN("JSON_DETAILED") }, BUILDER(Create_func_json_detailed)},
5600+
{ { STRING_WITH_LEN("JSON_EQUALS") }, BUILDER(Create_func_json_equals)},
55775601
{ { STRING_WITH_LEN("JSON_EXISTS") }, BUILDER(Create_func_json_exists)},
55785602
{ { STRING_WITH_LEN("JSON_EXTRACT") }, BUILDER(Create_func_json_extract)},
55795603
{ { STRING_WITH_LEN("JSON_INSERT") }, BUILDER(Create_func_json_insert)},

sql/item_jsonfunc.cc

Lines changed: 60 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -393,6 +393,66 @@ longlong Item_func_json_valid::val_int()
393393
}
394394

395395

396+
bool Item_func_json_equals::fix_length_and_dec()
397+
{
398+
if (Item_bool_func::fix_length_and_dec())
399+
return TRUE;
400+
set_maybe_null();
401+
return FALSE;
402+
}
403+
404+
405+
longlong Item_func_json_equals::val_int()
406+
{
407+
longlong result= 0;
408+
409+
String a_tmp, b_tmp;
410+
411+
String *a= args[0]->val_json(&a_tmp);
412+
String *b= args[1]->val_json(&b_tmp);
413+
414+
DYNAMIC_STRING a_res;
415+
if (init_dynamic_string(&a_res, NULL, 0, 0))
416+
{
417+
null_value= 1;
418+
return 1;
419+
}
420+
421+
DYNAMIC_STRING b_res;
422+
if (init_dynamic_string(&b_res, NULL, 0, 0))
423+
{
424+
dynstr_free(&a_res);
425+
null_value= 1;
426+
return 1;
427+
}
428+
429+
if ((null_value= args[0]->null_value || args[1]->null_value))
430+
{
431+
null_value= 1;
432+
goto end;
433+
}
434+
435+
if (json_normalize(&a_res, a->c_ptr(), a->length(), a->charset()))
436+
{
437+
null_value= 1;
438+
goto end;
439+
}
440+
441+
if (json_normalize(&b_res, b->c_ptr(), b->length(), b->charset()))
442+
{
443+
null_value= 1;
444+
goto end;
445+
}
446+
447+
result= strcmp(a_res.str, b_res.str) ? 0 : 1;
448+
449+
end:
450+
dynstr_free(&b_res);
451+
dynstr_free(&a_res);
452+
return result;
453+
}
454+
455+
396456
bool Item_func_json_exists::fix_length_and_dec()
397457
{
398458
if (Item_bool_func::fix_length_and_dec())

sql/item_jsonfunc.h

Lines changed: 17 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -107,6 +107,23 @@ class Item_func_json_valid: public Item_bool_func
107107
};
108108

109109

110+
class Item_func_json_equals: public Item_bool_func
111+
{
112+
public:
113+
Item_func_json_equals(THD *thd, Item *a, Item *b):
114+
Item_bool_func(thd, a, b) {}
115+
LEX_CSTRING func_name_cstring() const override
116+
{
117+
static LEX_CSTRING name= {STRING_WITH_LEN("json_equals") };
118+
return name;
119+
}
120+
bool fix_length_and_dec() override;
121+
Item *get_copy(THD *thd) override
122+
{ return get_item_copy<Item_func_json_equals>(thd, this); }
123+
longlong val_int() override;
124+
};
125+
126+
110127
class Item_func_json_exists: public Item_bool_func
111128
{
112129
protected:

0 commit comments

Comments
 (0)