Skip to content

Commit fcde341

Browse files
erichermancvicentiu
andcommitted
MDEV-16375 Function to normalize a json value
This patch implements JSON_NORMALIZE SQL function. Co-authored-by: Vicențiu Ciorbaru <vicentiu@mariadb.org>
1 parent 105e414 commit fcde341

File tree

5 files changed

+221
-0
lines changed

5 files changed

+221
-0
lines changed

mysql-test/main/json_normalize.result

Lines changed: 77 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,77 @@
1+
set names utf8;
2+
create table t1 (json json);
3+
show create table t1;
4+
Table Create Table
5+
t1 CREATE TABLE `t1` (
6+
`json` longtext CHARACTER SET utf8mb4 COLLATE utf8mb4_bin DEFAULT NULL CHECK (json_valid(`json`))
7+
) ENGINE=MyISAM DEFAULT CHARSET=latin1
8+
insert into t1 values
9+
('{ }'),
10+
('[ ]'),
11+
('{ "foo" : "bar" }'),
12+
('{ "foo" : "bar", "baz" : "whatever" }'),
13+
('[ 1.2, 0.0, "text", 0, null, true, false ]'),
14+
('[ "string", { "key" : "val", "a" : "b", "c" : [ 10, 9, 8, "seven", 11 ] }]'),
15+
('{ "ăț€": "val1", "âț€":"val2" }');
16+
select json, json_normalize(json) from t1
17+
order by json;
18+
json json_normalize(json)
19+
[ ] []
20+
[ "string", { "key" : "val", "a" : "b", "c" : [ 10, 9, 8, "seven", 11 ] }] ["string",{"a":"b","c":[1.0E1,9.0E0,8.0E0,"seven",1.1E1],"key":"val"}]
21+
[ 1.2, 0.0, "text", 0, null, true, false ] [1.2E0,0.0E0,"text",0.0E0,null,true,false]
22+
{ } {}
23+
{ "foo" : "bar" } {"foo":"bar"}
24+
{ "foo" : "bar", "baz" : "whatever" } {"baz":"whatever","foo":"bar"}
25+
{ "ăț€": "val1", "âț€":"val2" } {"âț€":"val2","ăț€":"val1"}
26+
create view v1 as (select json, json_normalize(json) norm_json from t1);
27+
show create view v1;
28+
View Create View character_set_client collation_connection
29+
v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v1` AS (select `t1`.`json` AS `json`,json_normalize(`t1`.`json`) AS `norm_json` from `t1`) utf8mb3 utf8mb3_general_ci
30+
select * from v1
31+
order by json;
32+
json norm_json
33+
[ ] []
34+
[ "string", { "key" : "val", "a" : "b", "c" : [ 10, 9, 8, "seven", 11 ] }] ["string",{"a":"b","c":[1.0E1,9.0E0,8.0E0,"seven",1.1E1],"key":"val"}]
35+
[ 1.2, 0.0, "text", 0, null, true, false ] [1.2E0,0.0E0,"text",0.0E0,null,true,false]
36+
{ } {}
37+
{ "foo" : "bar" } {"foo":"bar"}
38+
{ "foo" : "bar", "baz" : "whatever" } {"baz":"whatever","foo":"bar"}
39+
{ "ăț€": "val1", "âț€":"val2" } {"âț€":"val2","ăț€":"val1"}
40+
select json_normalize(NULL);
41+
json_normalize(NULL)
42+
NULL
43+
select json_normalize('{ "invalid": "no_close"');
44+
json_normalize('{ "invalid": "no_close"')
45+
NULL
46+
drop table t1;
47+
drop view v1;
48+
create table t1 (text varchar(200) character set 'latin1');
49+
insert into t1 values (unhex('22E522'));
50+
create table t2 (text varchar(200) character set 'utf8mb4');
51+
insert into t2 SELECT * FROM t1;
52+
select t1.text, hex(t1.text) from t1;
53+
text hex(t1.text)
54+
"å" 22E522
55+
select t2.text, hex(t2.text) from t2;
56+
text hex(t2.text)
57+
"å" 22C3A522
58+
select t1.text
59+
, t2.text
60+
, replace(json_normalize(t1.text), unhex('C3A5'), unhex('C385'))
61+
, replace(json_normalize(t2.text), unhex('C3A5'), unhex('C385'))
62+
, hex(replace(json_normalize(t1.text), unhex('C3A5'), unhex('C385')))
63+
, hex(replace(json_normalize(t2.text), unhex('C3A5'), unhex('C385')))
64+
from t1, t2;
65+
text text replace(json_normalize(t1.text), unhex('C3A5'), unhex('C385')) replace(json_normalize(t2.text), unhex('C3A5'), unhex('C385')) hex(replace(json_normalize(t1.text), unhex('C3A5'), unhex('C385'))) hex(replace(json_normalize(t2.text), unhex('C3A5'), unhex('C385')))
66+
"å" "å" "Å" "Å" 22C38522 22C38522
67+
drop table t1;
68+
drop table t2;
69+
create table t1 (text varchar(1));
70+
insert into t1 values ('0');
71+
select concat_ws(' ', t1.text, t1.text) from t1;
72+
concat_ws(' ', t1.text, t1.text)
73+
0 0
74+
select concat_ws(' ', json_normalize(t1.text), json_normalize(t1.text)) from t1;
75+
concat_ws(' ', json_normalize(t1.text), json_normalize(t1.text))
76+
0.0E0 0.0E0
77+
drop table t1;

mysql-test/main/json_normalize.test

Lines changed: 58 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,58 @@
1+
set names utf8;
2+
3+
create table t1 (json json);
4+
show create table t1;
5+
6+
7+
insert into t1 values
8+
('{ }'),
9+
('[ ]'),
10+
('{ "foo" : "bar" }'),
11+
('{ "foo" : "bar", "baz" : "whatever" }'),
12+
('[ 1.2, 0.0, "text", 0, null, true, false ]'),
13+
('[ "string", { "key" : "val", "a" : "b", "c" : [ 10, 9, 8, "seven", 11 ] }]'),
14+
('{ "ăț€": "val1", "âț€":"val2" }');
15+
16+
select json, json_normalize(json) from t1
17+
order by json;
18+
19+
20+
create view v1 as (select json, json_normalize(json) norm_json from t1);
21+
show create view v1;
22+
23+
select * from v1
24+
order by json;
25+
26+
select json_normalize(NULL);
27+
select json_normalize('{ "invalid": "no_close"');
28+
29+
drop table t1;
30+
drop view v1;
31+
32+
create table t1 (text varchar(200) character set 'latin1');
33+
insert into t1 values (unhex('22E522'));
34+
35+
create table t2 (text varchar(200) character set 'utf8mb4');
36+
insert into t2 SELECT * FROM t1;
37+
38+
select t1.text, hex(t1.text) from t1;
39+
select t2.text, hex(t2.text) from t2;
40+
41+
select t1.text
42+
, t2.text
43+
, replace(json_normalize(t1.text), unhex('C3A5'), unhex('C385'))
44+
, replace(json_normalize(t2.text), unhex('C3A5'), unhex('C385'))
45+
, hex(replace(json_normalize(t1.text), unhex('C3A5'), unhex('C385')))
46+
, hex(replace(json_normalize(t2.text), unhex('C3A5'), unhex('C385')))
47+
from t1, t2;
48+
49+
drop table t1;
50+
drop table t2;
51+
52+
create table t1 (text varchar(1));
53+
insert into t1 values ('0');
54+
55+
select concat_ws(' ', t1.text, t1.text) from t1;
56+
select concat_ws(' ', json_normalize(t1.text), json_normalize(t1.text)) from t1;
57+
58+
drop table t1;

sql/item_create.cc

Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -902,6 +902,19 @@ class Create_func_isnull : public Create_func_arg1
902902
};
903903

904904

905+
class Create_func_json_normalize : public Create_func_arg1
906+
{
907+
public:
908+
virtual Item *create_1_arg(THD *thd, Item *arg1);
909+
910+
static Create_func_json_normalize s_singleton;
911+
912+
protected:
913+
Create_func_json_normalize() {}
914+
virtual ~Create_func_json_normalize() {}
915+
};
916+
917+
905918
class Create_func_json_exists : public Create_func_arg2
906919
{
907920
public:
@@ -3596,6 +3609,15 @@ Create_func_isnull::create_1_arg(THD *thd, Item *arg1)
35963609
return new (thd->mem_root) Item_func_isnull(thd, arg1);
35973610
}
35983611

3612+
Create_func_json_normalize Create_func_json_normalize::s_singleton;
3613+
3614+
Item*
3615+
Create_func_json_normalize::create_1_arg(THD *thd, Item *arg1)
3616+
{
3617+
status_var_increment(thd->status_var.feature_json);
3618+
return new (thd->mem_root) Item_func_json_normalize(thd, arg1);
3619+
}
3620+
35993621

36003622
Create_func_json_exists Create_func_json_exists::s_singleton;
36013623

@@ -5561,6 +5583,7 @@ Native_func_registry func_array[] =
55615583
{ { STRING_WITH_LEN("JSON_MERGE") }, BUILDER(Create_func_json_merge)},
55625584
{ { STRING_WITH_LEN("JSON_MERGE_PATCH") }, BUILDER(Create_func_json_merge_patch)},
55635585
{ { STRING_WITH_LEN("JSON_MERGE_PRESERVE") }, BUILDER(Create_func_json_merge)},
5586+
{ { STRING_WITH_LEN("JSON_NORMALIZE") }, BUILDER(Create_func_json_normalize)},
55645587
{ { STRING_WITH_LEN("JSON_QUERY") }, BUILDER(Create_func_json_query)},
55655588
{ { STRING_WITH_LEN("JSON_QUOTE") }, BUILDER(Create_func_json_quote)},
55665589
{ { STRING_WITH_LEN("JSON_OBJECT") }, BUILDER(Create_func_json_object)},

sql/item_jsonfunc.cc

Lines changed: 45 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3885,3 +3885,48 @@ String* Item_func_json_objectagg::val_str(String* str)
38853885
}
38863886

38873887

3888+
String *Item_func_json_normalize::val_str(String *buf)
3889+
{
3890+
String tmp;
3891+
String *raw_json= args[0]->val_str(&tmp);
3892+
3893+
DYNAMIC_STRING normalized_json;
3894+
if (init_dynamic_string(&normalized_json, NULL, 0, 0))
3895+
{
3896+
null_value= 1;
3897+
return NULL;
3898+
}
3899+
3900+
null_value= args[0]->null_value;
3901+
if (null_value)
3902+
goto end;
3903+
3904+
if (json_normalize(&normalized_json,
3905+
raw_json->c_ptr(), raw_json->length(),
3906+
raw_json->charset()))
3907+
{
3908+
null_value= 1;
3909+
goto end;
3910+
}
3911+
3912+
buf->length(0);
3913+
if (buf->append(normalized_json.str, normalized_json.length))
3914+
{
3915+
null_value= 1;
3916+
goto end;
3917+
}
3918+
3919+
end:
3920+
dynstr_free(&normalized_json);
3921+
return null_value ? NULL : buf;
3922+
}
3923+
3924+
3925+
bool Item_func_json_normalize::fix_length_and_dec()
3926+
{
3927+
collation.set(&my_charset_utf8mb4_bin);
3928+
/* 0 becomes 0.0E0, thus one character becomes 5 chars */
3929+
fix_char_length_ulonglong((ulonglong) args[0]->max_char_length() * 5);
3930+
set_maybe_null();
3931+
return FALSE;
3932+
}

sql/item_jsonfunc.h

Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -443,6 +443,24 @@ class Item_func_json_merge_patch: public Item_func_json_merge
443443
{ return get_item_copy<Item_func_json_merge_patch>(thd, this); }
444444
};
445445

446+
447+
class Item_func_json_normalize: public Item_json_func
448+
{
449+
public:
450+
Item_func_json_normalize(THD *thd, Item *a):
451+
Item_json_func(thd, a) {}
452+
String *val_str(String *) override;
453+
LEX_CSTRING func_name_cstring() const override
454+
{
455+
static LEX_CSTRING name= {STRING_WITH_LEN("json_normalize") };
456+
return name;
457+
}
458+
bool fix_length_and_dec() override;
459+
Item *get_copy(THD *thd) override
460+
{ return get_item_copy<Item_func_json_normalize>(thd, this); }
461+
};
462+
463+
446464
class Item_func_json_length: public Item_long_func
447465
{
448466
bool check_arguments() const override

0 commit comments

Comments
 (0)