MDEV-17399 Add support for JSON_TABLE.

The specific table handler for the table functions was introduced,
and used to implement JSON_TABLE.
This commit is contained in:
Alexey Botchkov 2021-03-17 09:03:45 +04:00
parent a3099a3b4a
commit e9fd327ee3
40 changed files with 6001 additions and 43 deletions

View File

@ -134,6 +134,7 @@ SET(SQL_EMBEDDED_SOURCES emb_qcache.cc libmysqld.c lib_sql.cc
../sql/item_vers.cc
../sql/opt_trace.cc
../sql/xa.cc
../sql/json_table.cc
${GEN_SOURCES}
${MYSYS_LIBWRAP_SOURCE}
)

View File

@ -9186,4 +9186,32 @@ json_detailed(json_extract(trace, '$**.lateral_derived'))
}
]
drop table t1,t2;
#
# Test table functions.
#
CREATE TABLE t1(id INT, f1 JSON);
INSERT INTO t1 VALUES (1, '{\"1\": 1}'), (2, '{\"1\": 2}'), (3, '{\"1\": 3}'),
(4, '{\"1\": 4}'), (5, '{\"1\": 5}'), (6, '{\"1\": 6}');
SELECT * FROM t1 WHERE id IN
(SELECT id FROM t1 as tt2,
JSON_TABLE(f1, "$" COLUMNS (jf FOR ORDINALITY)) AS tbl);
id f1
1 {"1": 1}
2 {"1": 2}
3 {"1": 3}
4 {"1": 4}
5 {"1": 5}
6 {"1": 6}
select json_detailed(json_extract(trace, '$**.best_join_order'))
from information_schema.OPTIMIZER_TRACE;
json_detailed(json_extract(trace, '$**.best_join_order'))
[
[
"t1",
"<subquery2>"
]
]
DROP TABLE t1;
# End of 10.6 tests
set optimizer_trace='enabled=off';

View File

@ -837,4 +837,22 @@ from
information_schema.optimizer_trace;
drop table t1,t2;
--echo #
--echo # Test table functions.
--echo #
CREATE TABLE t1(id INT, f1 JSON);
INSERT INTO t1 VALUES (1, '{\"1\": 1}'), (2, '{\"1\": 2}'), (3, '{\"1\": 3}'),
(4, '{\"1\": 4}'), (5, '{\"1\": 5}'), (6, '{\"1\": 6}');
SELECT * FROM t1 WHERE id IN
(SELECT id FROM t1 as tt2,
JSON_TABLE(f1, "$" COLUMNS (jf FOR ORDINALITY)) AS tbl);
select json_detailed(json_extract(trace, '$**.best_join_order'))
from information_schema.OPTIMIZER_TRACE;
DROP TABLE t1;
--echo # End of 10.6 tests
set optimizer_trace='enabled=off';

View File

@ -2211,6 +2211,22 @@ drop table t1;
# MDEV-24858 SIGABRT in DbugExit from my_malloc in Query_cache::init_cache Regression
#
set global Query_cache_size=18446744073709547520;
#
# MDEV-22301 JSON_TABLE: Queries are not inserted into query cache.
#
create table t1 (a text);
insert into t1 values ('{"a":"foo"}');
flush status;
SHOW STATUS LIKE 'Qcache_inserts';
Variable_name Value
Qcache_inserts 0
select * from t1, json_table(t1.a, '$' columns (f varchar(20) path '$.a')) as jt;
a f
{"a":"foo"} foo
SHOW STATUS LIKE 'Qcache_inserts';
Variable_name Value
Qcache_inserts 0
drop table t1;
restore defaults
SET GLOBAL query_cache_type= default;
SET GLOBAL query_cache_size=@save_query_cache_size;

View File

@ -1807,6 +1807,17 @@ drop table t1;
set global Query_cache_size=18446744073709547520;
--enable_warnings
--echo #
--echo # MDEV-22301 JSON_TABLE: Queries are not inserted into query cache.
--echo #
create table t1 (a text);
insert into t1 values ('{"a":"foo"}');
flush status;
SHOW STATUS LIKE 'Qcache_inserts';
select * from t1, json_table(t1.a, '$' columns (f varchar(20) path '$.a')) as jt;
SHOW STATUS LIKE 'Qcache_inserts';
drop table t1;
--echo restore defaults
SET GLOBAL query_cache_type= default;
SET GLOBAL query_cache_size=@save_query_cache_size;

View File

@ -1954,3 +1954,18 @@ connection default;
drop user user_11766767;
drop database mysqltest1;
drop database mysqltest2;
# Check that a user without access to the schema 'foo' cannot query
# a JSON_TABLE view in that schema.
CREATE SCHEMA foo;
CREATE VIEW foo.v AS SELECT * FROM JSON_TABLE('[1,2,3]', '$[*]' COLUMNS (num INT PATH '$[0]')) AS jt;
CREATE USER foo@localhost;
connect con1,localhost,foo,,;
SELECT * FROM foo.v;
ERROR 42000: SELECT command denied to user 'foo'@'localhost' for table 'v'
#
# Clean-up.
#
connection default;
disconnect con1;
drop user foo@localhost;
drop schema foo;

View File

@ -2205,5 +2205,24 @@ drop user user_11766767;
drop database mysqltest1;
drop database mysqltest2;
--echo # Check that a user without access to the schema 'foo' cannot query
--echo # a JSON_TABLE view in that schema.
CREATE SCHEMA foo;
CREATE VIEW foo.v AS SELECT * FROM JSON_TABLE('[1,2,3]', '$[*]' COLUMNS (num INT PATH '$[0]')) AS jt;
CREATE USER foo@localhost;
connect (con1,localhost,foo,,);
--error ER_TABLEACCESS_DENIED_ERROR
SELECT * FROM foo.v;
--echo #
--echo # Clean-up.
--echo #
connection default;
disconnect con1;
drop user foo@localhost;
drop schema foo;
# Wait till we reached the initial number of concurrent sessions
--source include/wait_until_count_sessions.inc

View File

@ -0,0 +1,466 @@
select * from json_table('[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]', '$[*]' COLUMNS( a INT PATH '$.a')) as tt;
a
1
2
select * from JSON_TABLE( '[ {"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
a b
1 11
1 111
2 22
2 222
3 NULL
SELECT * FROM JSON_TABLE( '[ {"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'), NESTED PATH '$.b[*]' COLUMNS (c INT PATH '$') ) ) jt;
a b c
1 11 NULL
1 111 NULL
1 NULL 11
1 NULL 111
2 22 NULL
2 222 NULL
2 NULL 22
2 NULL 222
3 NULL NULL
create table t1 (id varchar(5), json varchar(1024));
insert into t1 values ('j1', '[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]');
insert into t1 values ('j2', '[{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}]');
select id, json, a from t1, json_table(t1.json, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a')) as tt;
id json a
j1 [{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}] 1
j1 [{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}] 2
j2 [{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}] 3
j2 [{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}] 4
j2 [{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}] 5
select * from t1, JSON_TABLE(t1.json, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (l_js_id FOR ORDINALITY, b INT PATH '$'))) as jt;
id json js_id a l_js_id b
j1 [{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}] 1 1 1 11
j1 [{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}] 1 1 2 111
j1 [{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}] 2 2 1 22
j1 [{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}] 2 2 2 222
j2 [{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}] 1 3 1 11
j2 [{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}] 1 3 2 111
j2 [{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}] 2 4 1 22
j2 [{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}] 2 4 2 222
j2 [{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}] 3 5 1 22
j2 [{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}] 3 5 2 222
select * from t1, JSON_TABLE(t1.no_field, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (l_js_id FOR ORDINALITY, b INT PATH '$'))) as jt;
ERROR 42S22: Unknown column 't1.no_field' in 'JSON_TABLE argument'
select * from t1, JSON_TABLE(t1.no_field, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (l_js_id FOR ORDINALITY, a INT PATH '$'))) as jt;
ERROR 42S21: Duplicate column name 'a'
DROP TABLE t1;
create table t1 (item_name varchar(32), item_props varchar(1024));
insert into t1 values ('Laptop', '{"color": "black", "price": 1000}');
insert into t1 values ('Jeans', '{"color": "blue", "price": 50}');
select * from t1 left join json_table(t1.item_props,'$' columns( color varchar(100) path '$.color')) as T on 1;
item_name item_props color
Laptop {"color": "black", "price": 1000} black
Jeans {"color": "blue", "price": 50} blue
select * from t1 right join json_table(t1.item_props,'$' columns( color varchar(100) path '$.color')) as T on 1;
ERROR 42000: Cross dependency found in OUTER JOIN; examine your ON conditions
DROP TABLE t1;
select * from JSON_TABLE( '[ {"xa": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
a b
101 11
101 111
2 22
2 222
3 NULL
select * from JSON_TABLE( '[ {"xa": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '202' on error, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
a b
NULL 11
NULL 111
2 22
2 222
3 NULL
select * from JSON_TABLE( '[ {"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
a b
NULL 11
NULL 111
2 22
2 222
3 NULL
select * from JSON_TABLE( '[ {"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '202' on error default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
a b
202 11
202 111
2 22
2 222
3 NULL
select * from JSON_TABLE( '[{"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3} xx YY]', '$[*]' COLUMNS( a INT PATH '$.a' default '202' on error default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
ERROR HY000: Syntax error in JSON text in argument 1 to function 'JSON_TABLE' at position 65
select * from JSON_TABLE( '[{"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' error on error default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
ERROR HY000: Field 'a' can't be set for JSON_TABLE 'jt'.
select * from json_table('{"a":0}',"$" columns(a decimal(1,1) path '$.a')) foo;
a
0.0
connect con1,localhost,root,,;
select a from json_table('{"a":0}',"$" columns(a for ordinality)) foo;
a
1
connection default;
disconnect con1;
create database db;
use db;
create table t (a text);
insert into t values ('{"foo":"bar"}');
create user u@localhost;
grant select (a) on db.t to u@localhost;
connect con1,localhost,u,,db;
select a from t;
a
{"foo":"bar"}
select * from t, json_table(t.a, '$' columns(f varchar(20) path '$.foo')) as jt;
a f
{"foo":"bar"} bar
connection default;
disconnect con1;
drop user u@localhost;
drop database db;
use test;
create table t1 (
color varchar(32),
price int
);
insert into t1 values ("red", 100), ("blue", 50);
insert into t1 select * from t1;
insert into t1 select * from t1;
set @save_optimizer_switch=@@optimizer_switch;
set optimizer_switch='firstmatch=off';
select * from
json_table('[{"color": "blue", "price": 50},
{"color": "red", "price": 100}]',
'$[*]' columns( color varchar(100) path '$.color',
price text path '$.price'
)
) as T
where
T.color in (select color from t1 where t1.price=T.price);
color price
blue 50
red 100
set @@optimizer_switch=@save_optimizer_switch;
drop table t1;
select * from
json_table(' [ {"color": "blue", "sizes": [1,2,3,4], "prices" : [10,20]},
{"color": "red", "sizes": [10,11,12,13,14], "prices" : [100,200,300]} ]',
'$[*]' columns(
color varchar(4) path '$.color',
seq0 for ordinality,
nested path '$.sizes[*]'
columns (seq1 for ordinality,
size int path '$'),
nested path '$.prices[*]'
columns (seq2 for ordinality,
price int path '$')
)
) as T;
color seq0 seq1 size seq2 price
blue 1 1 1 NULL NULL
blue 1 2 2 NULL NULL
blue 1 3 3 NULL NULL
blue 1 4 4 NULL NULL
blue 1 NULL NULL 1 10
blue 1 NULL NULL 2 20
red 2 1 10 NULL NULL
red 2 2 11 NULL NULL
red 2 3 12 NULL NULL
red 2 4 13 NULL NULL
red 2 5 14 NULL NULL
red 2 NULL NULL 1 100
red 2 NULL NULL 2 200
red 2 NULL NULL 3 300
select * from json_table('[{"color": "blue", "price": 50},
{"color": "red", "price": 100},
{"color": "rojo", "price": 10.0},
{"color": "blanco", "price": 11.0}]',
'$[*]' columns( color varchar(100) path '$.color',
price text path '$.price', seq for ordinality)) as T order by color desc;
color price seq
rojo 10.0 3
red 100 2
blue 50 1
blanco 11.0 4
create view v as select * from json_table('{"as":"b", "x":123}',"$" columns(a varchar(8) path '$.a' default '-' on empty, x int path '$.x')) x;
select * from v;
a x
- 123
show create table v;
View Create View character_set_client collation_connection
v CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v` AS select `x`.`a` AS `a`,`x`.`x` AS `x` from JSON_TABLE('{"as":"b", "x":123}', '$' COLUMNS (`a` varchar(8) PATH '$.a' DEFAULT '-' ON EMPTY, `x` int(11) PATH '$.x')) `x` latin1 latin1_swedish_ci
drop view v;
select * from json_table('{"as":"b", "x":123}',
"$" columns(a varchar(8) path '$.a' default '-' on empty null on error null on empty, x int path '$.x')) x;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'null on empty, x int path '$.x')) x' at line 2
select * from json_table('{"a":"foo","b":"bar"}', '$'
columns (v varchar(20) path '$.*')) as jt;
v
NULL
select * from json_table('{"a":"foo","b":"bar"}', '$'
columns (v varchar(20) path '$.*' default '-' on error)) as jt;
v
-
select * from json_table('{"b":"bar"}', '$'
columns (v varchar(20) path '$.*' default '-' on error)) as jt;
v
bar
create table t1 (a varchar(100));
insert into t1 values ('1');
select * from t1 as T, json_table(T.a, '$[*]' columns(color varchar(100) path '$.nonexistent', seq for ordinality)) as T;
ERROR 42000: Not unique table/alias: 'T'
drop table t1;
prepare s from 'select * from
json_table(?,
\'$[*]\' columns( color varchar(100) path \'$.color\',
price text path \'$.price\',
seq for ordinality)) as T
order by color desc; ';
execute s using '[{"color": "red", "price":1}, {"color":"brown", "price":2}]';
color price seq
red 1 1
brown 2 2
deallocate prepare s;
create view v2 as select * from json_table('[{"co\\\\lor": "blue", "price": 50}]', '$[*]' columns( color varchar(100) path '$.co\\\\lor') ) as T;
select * from v2;
color
blue
drop view v2;
explain format=json select * from
json_table('[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]', '$[*]' COLUMNS( a INT PATH '$.a')) as tt;
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "tt",
"access_type": "ALL",
"rows": 40,
"filtered": 100,
"table_function": "json_table"
}
}
}
explain select * from
json_table('[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]', '$[*]' COLUMNS( a INT PATH '$.a')) as tt;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE tt ALL NULL NULL NULL NULL 40 Table function: json_table
create view v1 as select * from
json_table('[{"color": "blue", "price": 50}]',
'$[*]' columns(color text path '$.nonexistent',
seq for ordinality)) as `ALIAS NOT QUOTED`;
select * from v1;
color seq
NULL 1
drop view v1;
create view v1 as select * from
json_table('[{"color": "blue", "price": 50},
{"color": "red", "price": 100}]',
'$[*]' columns(
color text path "$.QUOTES \" HERE \"",
color1 text path '$.QUOTES " HERE "',
color2 text path "$.QUOTES ' HERE '",
seq for ordinality)) as T;
select * from v1;
color color1 color2 seq
NULL NULL NULL 1
NULL NULL NULL 2
drop view v1;
CREATE TABLE t1 (x INT);
INSERT INTO t1 VALUES (1), (2), (3);
SELECT t1.x*2 m, jt.* FROM t1,
JSON_TABLE(m, '$[*]' COLUMNS (i INT PATH '$')) jt;
ERROR 42S22: Unknown column 'm' in 'JSON_TABLE argument'
DROP TABLE t1;
select * from json_table(JS3.size, '$' columns (size INT PATH '$.size')) as JS1, json_table(JS1.size, '$' columns (size INT PATH '$.size')) as JS2, json_table(JS1.size, '$' columns (size INT PATH '$.size')) as JS3 where 1;
ERROR 42S02: Unknown table 'JS3' in JSON_TABLE argument
create table t1 (json varchar(100) character set utf8);
insert into t1 values ('{"value":"АБВ"}');
create table tj1 as
select T.value
from t1, json_table(t1.json, '$' columns (value varchar(32) PATH '$.value')) T;
show create table tj1;
Table Create Table
tj1 CREATE TABLE `tj1` (
`value` varchar(32) CHARACTER SET utf8 DEFAULT NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1
drop table t1;
drop table tj1;
CREATE TABLE t1(id INT, f1 JSON);
INSERT INTO t1 VALUES
(1, '{\"1\": 1}'),
(2, '{\"1\": 2}'),
(3, '{\"1\": 3}'),
(4, '{\"1\": 4}'),
(5, '{\"1\": 5}'),
(6, '{\"1\": 6}');
ANALYZE TABLE t1;
Table Op Msg_type Msg_text
test.t1 analyze status Engine-independent statistics collected
test.t1 analyze Warning Engine-independent statistics are not collected for column 'f1'
test.t1 analyze status OK
SELECT * FROM JSON_TABLE(tt3.f1, "$" COLUMNS (id FOR ORDINALITY)) AS tbl STRAIGHT_JOIN t1 AS tt3;
ERROR 42S02: Unknown table 'tt3' in JSON_TABLE argument
SELECT * FROM t1 as jj1,
(SELECT tt2.*
FROM
t1 as tt2,
JSON_TABLE(tt3.f1, "$" COLUMNS (id FOR ORDINALITY)) AS tbl
STRAIGHT_JOIN
t1 AS tt3
) dt
ORDER BY 1,3 LIMIT 10;
ERROR 42S22: Unknown column 'tt3.f1' in 'JSON_TABLE argument'
drop table t1;
select collation(x) from
JSON_TABLE('["abc"]', '$[*]' COLUMNS (x VARCHAR(10) CHARSET latin1 PATH '$')) tbl;
collation(x)
latin1_swedish_ci
SELECT * FROM JSON_TABLE('{"x":1, "y":2}', _utf8mb4'$' COLUMNS (NESTED PATH _utf8mb4'$.x'
COLUMNS(y INT PATH _utf8mb4'$.y' DEFAULT _utf8mb4'1' ON EMPTY DEFAULT _utf8mb4'2' ON ERROR))) jt;
y
1
select * from json_table(
'{"name":"t-shirt", "colors": ["yellow", "blue"],"sizes": ["small", "medium", "large"]}',
'$' columns(name varchar(32) path '$.name',
nested path '$.colors[*]' columns (
color varchar(32) path '$',
nested path '$.sizes[*]' columns (
size varchar(32) path '$'
)))) as t;
name color size
t-shirt yellow NULL
t-shirt blue NULL
SELECT x, length(x) FROM
JSON_TABLE('{}', '$' COLUMNS (x VARCHAR(10) PATH '$.x' DEFAULT 'abcdefg' ON EMPTY)) jt;
x length(x)
abcdefg 7
select * from
json_table('[{"a":"aa"}, {"b":null}]', '$[*]'
columns (col1 int path '$.b' default '456' on empty)) as tt;
col1
456
NULL
select * from
json_table('[{"a":"aa"}, {"b":true}]', '$[*]'
columns (col1 int path '$.b' default '456' on empty)) as tt;
col1
456
1
select * from
json_table('[{"a":"aa"}, {"b":false}]', '$[*]'
columns (col1 int path '$.b' default '456' on empty)) as tt;
col1
456
0
select * from
json_table('[{"a":"aa"}, {"b":null}]', '$[*]'
columns (col1 varchar(100) path '$.b' default '456' on empty)) as tt;
col1
456
NULL
select * from
json_table('[{"a":"aa"}, {"b":true}]', '$[*]'
columns (col1 varchar(100) path '$.b' default '456' on empty)) as tt;
col1
456
true
select * from
json_table('[{"a":"aa"}, {"b":false}]', '$[*]'
columns (col1 varchar(100) path '$.b' default '456' on empty)) as tt;
col1
456
false
select * from
json_table( '[{"a":"asd"}, {"a":123}, {"a":[]}, {"a":{}} ]', '$[*]'
columns (id for ordinality,
intcol int path '$.a' default '1234' on empty default '5678' on error)
) as tt;
id intcol
1 5678
2 123
3 5678
4 5678
SELECT COUNT(*) FROM JSON_TABLE('[1, 2]', '$[*]' COLUMNS( I INT PATH '$')) tt;
COUNT(*)
2
create table t1 (a int);
insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t2 (js json, b int);
insert into t2 select '[1,2,3]',A.a from t1 A, t1 B;
explain select * from t1,
(select * from t2, json_table(t2.js, '$[*]' columns (o for ordinality)) as jt) as TT2
where 1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 10
1 SIMPLE t2 ALL NULL NULL NULL NULL 100 Using join buffer (flat, BNL join)
1 SIMPLE jt ALL NULL NULL NULL NULL 40 Table function: json_table
drop table t1, t2;
CREATE TABLE t1 (x INT);
INSERT INTO t1 VALUES (1);
CREATE TABLE t2 (j JSON);
INSERT INTO t2 (j) VALUES ('[1,2,3]');
SELECT * FROM t1 RIGHT JOIN
(SELECT o FROM t2, JSON_TABLE(j, '$[*]' COLUMNS (o FOR ORDINALITY)) AS jt) AS t3 ON (t3.o = t1.x);
x o
1 1
NULL 2
NULL 3
DROP TABLE t1, t2;
create table t20 (a int not null);
create table t21 (a int not null primary key, js varchar(100));
insert into t20 values (1),(2);
insert into t21 values (1, '{"a":100}');
explain select t20.a, jt1.ab
from t20 left join t21 on t20.a=t21.a
join JSON_TABLE(t21.js,'$' COLUMNS (ab INT PATH '$.a')) AS jt1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t20 ALL NULL NULL NULL NULL 2
1 SIMPLE t21 eq_ref PRIMARY PRIMARY 4 test.t20.a 1
1 SIMPLE jt1 ALL NULL NULL NULL NULL 40 Table function: json_table
drop table t20, t21;
select * from
json_table(
'[
{"name": "X",
"colors":["blue"], "sizes": [1,2,3,4], "prices" : [10,20]},
{"name": "Y",
"colors":["red"], "sizes": [10,11], "prices" : [100,200,300]}
]',
'$[*]' columns
(
seq0 for ordinality,
name varchar(4) path '$.name',
nested path '$.colors[*]' columns (
seq1 for ordinality,
color text path '$'
),
nested path '$.sizes[*]' columns (
seq2 for ordinality,
size int path '$'
),
nested path '$.prices[*]' columns (
seq3 for ordinality,
price int path '$'
)
)
) as T order by seq0, name;
seq0 name seq1 color seq2 size seq3 price
1 X NULL NULL NULL NULL 1 10
1 X NULL NULL NULL NULL 2 20
1 X NULL NULL 1 1 NULL NULL
1 X NULL NULL 2 2 NULL NULL
1 X NULL NULL 3 3 NULL NULL
1 X NULL NULL 4 4 NULL NULL
1 X 1 blue NULL NULL NULL NULL
2 Y NULL NULL NULL NULL 1 100
2 Y NULL NULL NULL NULL 2 200
2 Y NULL NULL NULL NULL 3 300
2 Y NULL NULL 1 10 NULL NULL
2 Y NULL NULL 2 11 NULL NULL
2 Y 1 red NULL NULL NULL NULL
select * from json_table('[]', '$' COLUMNS(x FOR ORDINALITY));
ERROR HY000: Every table function must have an alias.
select min(x) from json_table('[]', '$' COLUMNS(x FOR ORDINALITY)) a;
min(x)
1
#
# End of 10.5 tests
#

File diff suppressed because it is too large Load Diff

View File

@ -0,0 +1,351 @@
select * from json_table('[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]', '$[*]' COLUMNS( a INT PATH '$.a')) as tt;
select * from JSON_TABLE( '[ {"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
SELECT * FROM JSON_TABLE( '[ {"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'), NESTED PATH '$.b[*]' COLUMNS (c INT PATH '$') ) ) jt;
create table t1 (id varchar(5), json varchar(1024));
insert into t1 values ('j1', '[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]');
insert into t1 values ('j2', '[{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}]');
select id, json, a from t1, json_table(t1.json, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a')) as tt;
select * from t1, JSON_TABLE(t1.json, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (l_js_id FOR ORDINALITY, b INT PATH '$'))) as jt;
--error ER_BAD_FIELD_ERROR
select * from t1, JSON_TABLE(t1.no_field, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (l_js_id FOR ORDINALITY, b INT PATH '$'))) as jt;
--error ER_DUP_FIELDNAME
select * from t1, JSON_TABLE(t1.no_field, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (l_js_id FOR ORDINALITY, a INT PATH '$'))) as jt;
DROP TABLE t1;
create table t1 (item_name varchar(32), item_props varchar(1024));
insert into t1 values ('Laptop', '{"color": "black", "price": 1000}');
insert into t1 values ('Jeans', '{"color": "blue", "price": 50}');
select * from t1 left join json_table(t1.item_props,'$' columns( color varchar(100) path '$.color')) as T on 1;
--error ER_WRONG_OUTER_JOIN
select * from t1 right join json_table(t1.item_props,'$' columns( color varchar(100) path '$.color')) as T on 1;
DROP TABLE t1;
select * from JSON_TABLE( '[ {"xa": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
select * from JSON_TABLE( '[ {"xa": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '202' on error, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
select * from JSON_TABLE( '[ {"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
select * from JSON_TABLE( '[ {"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '202' on error default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
--error ER_JSON_SYNTAX
select * from JSON_TABLE( '[{"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3} xx YY]', '$[*]' COLUMNS( a INT PATH '$.a' default '202' on error default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
--error ER_JSON_TABLE_ERROR_ON_FIELD
select * from JSON_TABLE( '[{"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' error on error default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;
#
# MDEV-22290 JSON_TABLE: Decimal type with M equal D causes Assertion
# `scale <= precision' failure
#
select * from json_table('{"a":0}',"$" columns(a decimal(1,1) path '$.a')) foo;
#
# MDEV-22291 JSON_TABLE: SELECT from json_table does not work without default database
#
connect (con1,localhost,root,,);
select a from json_table('{"a":0}',"$" columns(a for ordinality)) foo;
connection default;
disconnect con1;
#
# MDEV-22302 JSON_TABLE: Column privilege is insufficient for query with json_table
#
create database db;
use db;
create table t (a text);
insert into t values ('{"foo":"bar"}');
create user u@localhost;
grant select (a) on db.t to u@localhost;
--connect (con1,localhost,u,,db)
select a from t;
select * from t, json_table(t.a, '$' columns(f varchar(20) path '$.foo')) as jt;
connection default;
disconnect con1;
drop user u@localhost;
drop database db;
use test;
create table t1 (
color varchar(32),
price int
);
insert into t1 values ("red", 100), ("blue", 50);
insert into t1 select * from t1;
insert into t1 select * from t1;
set @save_optimizer_switch=@@optimizer_switch;
set optimizer_switch='firstmatch=off';
select * from
json_table('[{"color": "blue", "price": 50},
{"color": "red", "price": 100}]',
'$[*]' columns( color varchar(100) path '$.color',
price text path '$.price'
)
) as T
where
T.color in (select color from t1 where t1.price=T.price);
set @@optimizer_switch=@save_optimizer_switch;
drop table t1;
select * from
json_table(' [ {"color": "blue", "sizes": [1,2,3,4], "prices" : [10,20]},
{"color": "red", "sizes": [10,11,12,13,14], "prices" : [100,200,300]} ]',
'$[*]' columns(
color varchar(4) path '$.color',
seq0 for ordinality,
nested path '$.sizes[*]'
columns (seq1 for ordinality,
size int path '$'),
nested path '$.prices[*]'
columns (seq2 for ordinality,
price int path '$')
)
) as T;
select * from json_table('[{"color": "blue", "price": 50},
{"color": "red", "price": 100},
{"color": "rojo", "price": 10.0},
{"color": "blanco", "price": 11.0}]',
'$[*]' columns( color varchar(100) path '$.color',
price text path '$.price', seq for ordinality)) as T order by color desc;
create view v as select * from json_table('{"as":"b", "x":123}',"$" columns(a varchar(8) path '$.a' default '-' on empty, x int path '$.x')) x;
select * from v;
show create table v;
drop view v;
--error ER_PARSE_ERROR
select * from json_table('{"as":"b", "x":123}',
"$" columns(a varchar(8) path '$.a' default '-' on empty null on error null on empty, x int path '$.x')) x;
select * from json_table('{"a":"foo","b":"bar"}', '$'
columns (v varchar(20) path '$.*')) as jt;
select * from json_table('{"a":"foo","b":"bar"}', '$'
columns (v varchar(20) path '$.*' default '-' on error)) as jt;
select * from json_table('{"b":"bar"}', '$'
columns (v varchar(20) path '$.*' default '-' on error)) as jt;
create table t1 (a varchar(100));
insert into t1 values ('1');
--error ER_NONUNIQ_TABLE
select * from t1 as T, json_table(T.a, '$[*]' columns(color varchar(100) path '$.nonexistent', seq for ordinality)) as T;
drop table t1;
prepare s from 'select * from
json_table(?,
\'$[*]\' columns( color varchar(100) path \'$.color\',
price text path \'$.price\',
seq for ordinality)) as T
order by color desc; ';
execute s using '[{"color": "red", "price":1}, {"color":"brown", "price":2}]';
deallocate prepare s;
create view v2 as select * from json_table('[{"co\\\\lor": "blue", "price": 50}]', '$[*]' columns( color varchar(100) path '$.co\\\\lor') ) as T;
select * from v2;
drop view v2;
explain format=json select * from
json_table('[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]', '$[*]' COLUMNS( a INT PATH '$.a')) as tt;
explain select * from
json_table('[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]', '$[*]' COLUMNS( a INT PATH '$.a')) as tt;
create view v1 as select * from
json_table('[{"color": "blue", "price": 50}]',
'$[*]' columns(color text path '$.nonexistent',
seq for ordinality)) as `ALIAS NOT QUOTED`;
select * from v1;
drop view v1;
create view v1 as select * from
json_table('[{"color": "blue", "price": 50},
{"color": "red", "price": 100}]',
'$[*]' columns(
color text path "$.QUOTES \" HERE \"",
color1 text path '$.QUOTES " HERE "',
color2 text path "$.QUOTES ' HERE '",
seq for ordinality)) as T;
select * from v1;
drop view v1;
CREATE TABLE t1 (x INT);
INSERT INTO t1 VALUES (1), (2), (3);
--error ER_BAD_FIELD_ERROR
SELECT t1.x*2 m, jt.* FROM t1,
JSON_TABLE(m, '$[*]' COLUMNS (i INT PATH '$')) jt;
DROP TABLE t1;
--error ER_UNKNOWN_TABLE
select * from json_table(JS3.size, '$' columns (size INT PATH '$.size')) as JS1, json_table(JS1.size, '$' columns (size INT PATH '$.size')) as JS2, json_table(JS1.size, '$' columns (size INT PATH '$.size')) as JS3 where 1;
create table t1 (json varchar(100) character set utf8);
insert into t1 values ('{"value":"АБВ"}');
create table tj1 as
select T.value
from t1, json_table(t1.json, '$' columns (value varchar(32) PATH '$.value')) T;
show create table tj1;
drop table t1;
drop table tj1;
CREATE TABLE t1(id INT, f1 JSON);
INSERT INTO t1 VALUES
(1, '{\"1\": 1}'),
(2, '{\"1\": 2}'),
(3, '{\"1\": 3}'),
(4, '{\"1\": 4}'),
(5, '{\"1\": 5}'),
(6, '{\"1\": 6}');
ANALYZE TABLE t1;
--error ER_UNKNOWN_TABLE
SELECT * FROM JSON_TABLE(tt3.f1, "$" COLUMNS (id FOR ORDINALITY)) AS tbl STRAIGHT_JOIN t1 AS tt3;
--error ER_BAD_FIELD_ERROR
SELECT * FROM t1 as jj1,
(SELECT tt2.*
FROM
t1 as tt2,
JSON_TABLE(tt3.f1, "$" COLUMNS (id FOR ORDINALITY)) AS tbl
STRAIGHT_JOIN
t1 AS tt3
) dt
ORDER BY 1,3 LIMIT 10;
drop table t1;
select collation(x) from
JSON_TABLE('["abc"]', '$[*]' COLUMNS (x VARCHAR(10) CHARSET latin1 PATH '$')) tbl;
SELECT * FROM JSON_TABLE('{"x":1, "y":2}', _utf8mb4'$' COLUMNS (NESTED PATH _utf8mb4'$.x'
COLUMNS(y INT PATH _utf8mb4'$.y' DEFAULT _utf8mb4'1' ON EMPTY DEFAULT _utf8mb4'2' ON ERROR))) jt;
select * from json_table(
'{"name":"t-shirt", "colors": ["yellow", "blue"],"sizes": ["small", "medium", "large"]}',
'$' columns(name varchar(32) path '$.name',
nested path '$.colors[*]' columns (
color varchar(32) path '$',
nested path '$.sizes[*]' columns (
size varchar(32) path '$'
)))) as t;
SELECT x, length(x) FROM
JSON_TABLE('{}', '$' COLUMNS (x VARCHAR(10) PATH '$.x' DEFAULT 'abcdefg' ON EMPTY)) jt;
# check how conversion works for JSON NULL, TRUE and FALSE
select * from
json_table('[{"a":"aa"}, {"b":null}]', '$[*]'
columns (col1 int path '$.b' default '456' on empty)) as tt;
select * from
json_table('[{"a":"aa"}, {"b":true}]', '$[*]'
columns (col1 int path '$.b' default '456' on empty)) as tt;
select * from
json_table('[{"a":"aa"}, {"b":false}]', '$[*]'
columns (col1 int path '$.b' default '456' on empty)) as tt;
select * from
json_table('[{"a":"aa"}, {"b":null}]', '$[*]'
columns (col1 varchar(100) path '$.b' default '456' on empty)) as tt;
select * from
json_table('[{"a":"aa"}, {"b":true}]', '$[*]'
columns (col1 varchar(100) path '$.b' default '456' on empty)) as tt;
select * from
json_table('[{"a":"aa"}, {"b":false}]', '$[*]'
columns (col1 varchar(100) path '$.b' default '456' on empty)) as tt;
select * from
json_table( '[{"a":"asd"}, {"a":123}, {"a":[]}, {"a":{}} ]', '$[*]'
columns (id for ordinality,
intcol int path '$.a' default '1234' on empty default '5678' on error)
) as tt;
SELECT COUNT(*) FROM JSON_TABLE('[1, 2]', '$[*]' COLUMNS( I INT PATH '$')) tt;
create table t1 (a int);
insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t2 (js json, b int);
insert into t2 select '[1,2,3]',A.a from t1 A, t1 B;
explain select * from t1,
(select * from t2, json_table(t2.js, '$[*]' columns (o for ordinality)) as jt) as TT2
where 1;
drop table t1, t2;
CREATE TABLE t1 (x INT);
INSERT INTO t1 VALUES (1);
CREATE TABLE t2 (j JSON);
INSERT INTO t2 (j) VALUES ('[1,2,3]');
--sorted_result
SELECT * FROM t1 RIGHT JOIN
(SELECT o FROM t2, JSON_TABLE(j, '$[*]' COLUMNS (o FOR ORDINALITY)) AS jt) AS t3 ON (t3.o = t1.x);
DROP TABLE t1, t2;
create table t20 (a int not null);
create table t21 (a int not null primary key, js varchar(100));
insert into t20 values (1),(2);
insert into t21 values (1, '{"a":100}');
explain select t20.a, jt1.ab
from t20 left join t21 on t20.a=t21.a
join JSON_TABLE(t21.js,'$' COLUMNS (ab INT PATH '$.a')) AS jt1;
drop table t20, t21;
select * from
json_table(
'[
{"name": "X",
"colors":["blue"], "sizes": [1,2,3,4], "prices" : [10,20]},
{"name": "Y",
"colors":["red"], "sizes": [10,11], "prices" : [100,200,300]}
]',
'$[*]' columns
(
seq0 for ordinality,
name varchar(4) path '$.name',
nested path '$.colors[*]' columns (
seq1 for ordinality,
color text path '$'
),
nested path '$.sizes[*]' columns (
seq2 for ordinality,
size int path '$'
),
nested path '$.prices[*]' columns (
seq3 for ordinality,
price int path '$'
)
)
) as T order by seq0, name;
# MDEV-25140 Success of query execution depends on the outcome of previous queries.
--error ER_JSON_TABLE_ALIAS_REQUIRED
select * from json_table('[]', '$' COLUMNS(x FOR ORDINALITY));
select min(x) from json_table('[]', '$' COLUMNS(x FOR ORDINALITY)) a;
--echo #
--echo # End of 10.5 tests
--echo #

File diff suppressed because it is too large Load Diff

View File

@ -164,6 +164,7 @@ SET (SQL_SOURCE
rowid_filter.cc rowid_filter.h
opt_trace.cc
table_cache.cc encryption.cc temporary_tables.cc
json_table.cc
proxy_protocol.cc backup.cc xa.cc
${CMAKE_CURRENT_BINARY_DIR}/lex_hash.h
${CMAKE_CURRENT_BINARY_DIR}/lex_token.h

View File

@ -1753,7 +1753,8 @@ bool Field_num::get_int(CHARSET_INFO *cs, const char *from, size_t len,
if (get_thd()->count_cuted_fields > CHECK_FIELD_EXPRESSION &&
check_int(cs, from, len, end, error))
return 1;
return 0;
return error && get_thd()->count_cuted_fields == CHECK_FIELD_EXPRESSION;
out_of_range:
set_warning(ER_WARN_DATA_OUT_OF_RANGE, 1);

View File

@ -1611,6 +1611,7 @@ public:
virtual longlong val_time_packed(THD *thd);
virtual const TYPELIB *get_typelib() const { return NULL; }
virtual CHARSET_INFO *charset() const= 0;
virtual void change_charset(const DTCollation &new_cs) {}
virtual const DTCollation &dtcollation() const= 0;
virtual CHARSET_INFO *charset_for_protocol(void) const
{ return binary() ? &my_charset_bin : charset(); }
@ -2109,6 +2110,12 @@ public:
{
return m_collation;
}
void change_charset(const DTCollation &new_cs) override
{
field_length= (field_length * new_cs.collation->mbmaxlen) /
m_collation.collation->mbmaxlen;
m_collation= new_cs;
}
bool binary() const override { return field_charset() == &my_charset_bin; }
uint32 max_display_length() const override { return field_length; }
uint32 character_octet_length() const override { return field_length; }

View File

@ -619,10 +619,12 @@ int ha_finalize_handlerton(st_plugin_int *plugin)
}
const char *hton_no_exts[]= { 0 };
int ha_initialize_handlerton(st_plugin_int *plugin)
{
handlerton *hton;
static const char *no_exts[]= { 0 };
DBUG_ENTER("ha_initialize_handlerton");
DBUG_PRINT("plugin", ("initialize plugin: '%s'", plugin->name.str));
@ -635,7 +637,7 @@ int ha_initialize_handlerton(st_plugin_int *plugin)
goto err_no_hton_memory;
}
hton->tablefile_extensions= no_exts;
hton->tablefile_extensions= hton_no_exts;
hton->discover_table_names= hton_ext_based_table_discovery;
hton->drop_table= hton_drop_table;

View File

@ -1724,6 +1724,8 @@ struct handlerton
};
extern const char *hton_no_exts[];
static inline LEX_CSTRING *hton_name(const handlerton *hton)
{
return &(hton2plugin[hton->slot]->name);

View File

@ -115,10 +115,6 @@ String *Item_func_geometry_from_wkb::val_str(String *str)
}
void report_json_error_ex(String *js, json_engine_t *je,
const char *fname, int n_param,
Sql_condition::enum_warning_level lv);
String *Item_func_geometry_from_json::val_str(String *str)
{
DBUG_ASSERT(fixed == 1);
@ -178,7 +174,8 @@ String *Item_func_geometry_from_json::val_str(String *str)
my_error(ER_GIS_INVALID_DATA, MYF(0), "ST_GeomFromGeoJSON");
break;
default:
report_json_error_ex(js, &je, func_name(), 0, Sql_condition::WARN_LEVEL_WARN);
report_json_error_ex(js->ptr(), &je, func_name(), 0,
Sql_condition::WARN_LEVEL_WARN);
return NULL;
}

View File

@ -247,15 +247,15 @@ error:
#define report_json_error(js, je, n_param) \
report_json_error_ex(js, je, func_name(), n_param, \
report_json_error_ex(js->ptr(), je, func_name(), n_param, \
Sql_condition::WARN_LEVEL_WARN)
void report_json_error_ex(String *js, json_engine_t *je,
void report_json_error_ex(const char *js, json_engine_t *je,
const char *fname, int n_param,
Sql_condition::enum_warning_level lv)
{
THD *thd= current_thd;
int position= (int)((const char *) je->s.c_str - js->ptr());
int position= (int)((const char *) je->s.c_str - js);
uint code;
n_param++;
@ -285,16 +285,22 @@ void report_json_error_ex(String *js, json_engine_t *je,
case JE_DEPTH:
code= ER_JSON_DEPTH;
push_warning_printf(thd, lv, code, ER_THD(thd, code), JSON_DEPTH_LIMIT,
n_param, fname, position);
if (lv == Sql_condition::WARN_LEVEL_ERROR)
my_error(code, MYF(0), JSON_DEPTH_LIMIT, n_param, fname, position);
else
push_warning_printf(thd, lv, code, ER_THD(thd, code), JSON_DEPTH_LIMIT,
n_param, fname, position);
return;
default:
return;
}
push_warning_printf(thd, lv, code, ER_THD(thd, code),
n_param, fname, position);
if (lv == Sql_condition::WARN_LEVEL_ERROR)
my_error(code, MYF(0), n_param, fname, position);
else
push_warning_printf(thd, lv, code, ER_THD(thd, code),
n_param, fname, position);
}
@ -304,15 +310,15 @@ void report_json_error_ex(String *js, json_engine_t *je,
#define TRIVIAL_PATH_NOT_ALLOWED 3
#define report_path_error(js, je, n_param) \
report_path_error_ex(js, je, func_name(), n_param,\
report_path_error_ex(js->ptr(), je, func_name(), n_param,\
Sql_condition::WARN_LEVEL_WARN)
static void report_path_error_ex(String *ps, json_path_t *p,
const char *fname, int n_param,
Sql_condition::enum_warning_level lv)
void report_path_error_ex(const char *ps, json_path_t *p,
const char *fname, int n_param,
Sql_condition::enum_warning_level lv)
{
THD *thd= current_thd;
int position= (int)((const char *) p->s.c_str - ps->ptr() + 1);
int position= (int)((const char *) p->s.c_str - ps + 1);
uint code;
n_param++;
@ -331,8 +337,11 @@ static void report_path_error_ex(String *ps, json_path_t *p,
case JE_DEPTH:
code= ER_JSON_PATH_DEPTH;
push_warning_printf(thd, lv, code, ER_THD(thd, code),
JSON_DEPTH_LIMIT, n_param, fname, position);
if (lv == Sql_condition::WARN_LEVEL_ERROR)
my_error(code, MYF(0), JSON_DEPTH_LIMIT, n_param, fname, position);
else
push_warning_printf(thd, lv, code, ER_THD(thd, code),
JSON_DEPTH_LIMIT, n_param, fname, position);
return;
case NO_WILDCARD_ALLOWED:
@ -347,12 +356,14 @@ static void report_path_error_ex(String *ps, json_path_t *p,
default:
return;
}
push_warning_printf(thd, lv, code, ER_THD(thd, code),
n_param, fname, position);
if (lv == Sql_condition::WARN_LEVEL_ERROR)
my_error(code, MYF(0), n_param, fname, position);
else
push_warning_printf(thd, lv, code, ER_THD(thd, code),
n_param, fname, position);
}
/*
Checks if the path has '.*' '[*]' or '**' constructions
and sets the NO_WILDCARD_ALLOWED error if the case.

View File

@ -41,6 +41,13 @@ public:
};
void report_path_error_ex(const char *ps, json_path_t *p,
const char *fname, int n_param,
Sql_condition::enum_warning_level lv);
void report_json_error_ex(const char *js, json_engine_t *je,
const char *fname, int n_param,
Sql_condition::enum_warning_level lv);
class Json_engine_scan: public json_engine_t
{
public:

1286
sql/json_table.cc Normal file

File diff suppressed because it is too large Load Diff

256
sql/json_table.h Normal file
View File

@ -0,0 +1,256 @@
#ifndef JSON_TABLE_INCLUDED
#define JSON_TABLE_INCLUDED
/* Copyright (c) 2020, MariaDB Corporation. All rights reserved.
This program is free software; you can redistribute it and/or modify
it under the terms of the GNU General Public License as published by
the Free Software Foundation; version 2 of the License.
This program is distributed in the hope that it will be useful,
but WITHOUT ANY WARRANTY; without even the implied warranty of
MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
GNU General Public License for more details.
You should have received a copy of the GNU General Public License
along with this program; if not, write to the Free Software
Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1335 USA */
#include <json_lib.h>
class Json_table_column;
/*
The Json_table_nested_path represents the 'current nesting' level
for a set of JSON_TABLE columns.
Each column (Json_table_column instance) is linked with corresponding
'nested path' object and gets its piece of JSON to parse during the computation
phase.
The root 'nested_path' is always present as a part of Table_function_json_table,
then other 'nested_paths' can be created and linked into a tree structure when new
'NESTED PATH' is met. The nested 'nested_paths' are linked with 'm_nested', the same-level
'nested_paths' are linked with 'm_next_nested'.
So for instance
JSON_TABLE( '...', '$[*]'
COLUMNS( a INT PATH '$.a' ,
NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$',
NESTED PATH '$.c[*]' COLUMNS(x INT PATH '$')),
NESTED PATH '$.n[*]' COLUMNS (z INT PATH '$'))
results in 4 'nested_path' created:
root nested_b nested_c nested_n
m_path '$[*]' '$.b[*]' '$.c[*]' '$.n[*]
m_nested &nested_b &nested_c NULL NULL
n_next_nested NULL &nested_n NULL NULL
and 4 columns created:
a b x z
m_nest &root &nested_b &nested_c &nested_n
*/
class Json_table_nested_path : public Sql_alloc
{
public:
json_path_t m_path; /* The JSON Path to get the rows from */
bool m_null; // TRUE <=> producing a NULL-complemented row.
/*** Construction interface ***/
Json_table_nested_path():
m_null(TRUE), m_nested(NULL), m_next_nested(NULL)
{}
int set_path(THD *thd, const LEX_CSTRING &path);
/*** Methods for performing a scan ***/
void scan_start(CHARSET_INFO *i_cs, const uchar *str, const uchar *end);
int scan_next();
bool check_error(const char *str);
/*** Members for getting the values we've scanned to ***/
const uchar *get_value() { return m_engine.value_begin; }
const uchar *get_value_end() { return m_engine.s.str_end; }
/* Counts the rows produced. Used by FOR ORDINALITY columns */
longlong m_ordinality_counter;
int print(THD *thd, Field ***f, String *str,
List_iterator_fast<Json_table_column> &it,
Json_table_column **last_column);
private:
/* The head of the list of nested NESTED PATH statements. */
Json_table_nested_path *m_nested;
/* in the above list items are linked with the */
Json_table_nested_path *m_next_nested;
/*** Members describing NESTED PATH structure ***/
/* Parent nested path. The "root" path has this NULL */
Json_table_nested_path *m_parent;
/*** Members describing current JSON Path scan state ***/
/* The JSON Parser and JSON Path evaluator */
json_engine_t m_engine;
/* The path the parser is currently pointing to */
json_path_t m_cur_path;
/* The child NESTED PATH we're currently scanning */
Json_table_nested_path *m_cur_nested;
friend class Table_function_json_table;
};
/*
@brief
Describes the column definition in JSON_TABLE(...) syntax.
@detail
Has methods for printing/handling errors but otherwise it's a static
object.
*/
class Json_table_column : public Sql_alloc
{
public:
enum enum_type
{
FOR_ORDINALITY,
PATH,
EXISTS_PATH
};
enum enum_on_type
{
ON_EMPTY,
ON_ERROR
};
enum enum_on_response
{
RESPONSE_NOT_SPECIFIED,
RESPONSE_ERROR,
RESPONSE_NULL,
RESPONSE_DEFAULT
};
struct On_response
{
public:
Json_table_column::enum_on_response m_response;
LEX_CSTRING m_default;
int respond(Json_table_column *jc, Field *f);
int print(const char *name, String *str) const;
bool specified() const { return m_response != RESPONSE_NOT_SPECIFIED; }
};
enum_type m_column_type;
json_path_t m_path;
On_response m_on_error;
On_response m_on_empty;
Create_field *m_field;
Json_table_nested_path *m_nest;
CHARSET_INFO *m_explicit_cs;
CHARSET_INFO *m_defaults_cs;
void set(enum_type ctype)
{
m_column_type= ctype;
}
int set(THD *thd, enum_type ctype, const LEX_CSTRING &path);
Json_table_column(Create_field *f, Json_table_nested_path *nest) :
m_field(f), m_nest(nest)
{
m_on_error.m_response= RESPONSE_NOT_SPECIFIED;
m_on_empty.m_response= RESPONSE_NOT_SPECIFIED;
}
int print(THD *tnd, Field **f, String *str);
};
/*
Class represents the table function, the function
that returns the table as a result so supposed to appear
in the FROM list of the SELECT statement.
At the moment there is only one such function JSON_TABLE,
so the class named after it, but should be refactored
into the hierarchy root if we create more of that functions.
As the parser finds the table function in the list it
creates an instance of Table_function_json_table storing it
into the TABLE_LIST::table_function.
Then the ha_json_table instance is created based on it in
the create_table_for_function().
*/
class Table_function_json_table : public Sql_alloc
{
public:
/*** Basic properties of the original JSON_TABLE(...) ***/
Item *m_json; /* The JSON value to be parsed. */
/* The COLUMNS(...) part representation. */
Json_table_nested_path m_nested_path;
/* The list of table column definitions. */
List<Json_table_column> m_columns;
/*** Name resolution functions ***/
int setup(THD *thd, TABLE_LIST *sql_table, SELECT_LEX *s_lex);
/*** Functions for interaction with the Query Optimizer ***/
void fix_after_pullout(TABLE_LIST *sql_table,
st_select_lex *new_parent, bool merge);
void update_used_tables() { m_json->update_used_tables(); }
table_map used_tables() const { return m_dep_tables; }
bool join_cache_allowed() const { return !m_dep_tables; }
void get_estimates(ha_rows *out_rows,
double *scan_time, double *startup_cost);
int print(THD *thd, TABLE_LIST *sql_table,
String *str, enum_query_type query_type);
/*** Construction interface to be used from the parser ***/
Table_function_json_table(Item *json):
m_json(json)
{
cur_parent= &m_nested_path;
last_sibling_hook= &m_nested_path.m_nested;
}
void start_nested_path(Json_table_nested_path *np);
void end_nested_path();
Json_table_nested_path *get_cur_nested_path() { return cur_parent; }
/* SQL Parser: current column in JSON_TABLE (...) syntax */
Json_table_column *m_cur_json_table_column;
/* SQL Parser: charset of the current text literal */
CHARSET_INFO *m_text_literal_cs;
private:
/*
the JSON argument can be taken from other tables.
We have to mark these tables as dependent so the
mask of these dependent tables is calculated in ::setup().
*/
table_map m_dep_tables;
/* Current NESTED PATH level being parsed */
Json_table_nested_path *cur_parent;
/*
Pointer to the list tail where we add the next NESTED PATH.
It points to the cur_parnt->m_nested for the first nested
and prev_nested->m_next_nested for the coesequent ones.
*/
Json_table_nested_path **last_sibling_hook;
};
TABLE *create_table_for_function(THD *thd, TABLE_LIST *sql_table);
#endif /* JSON_TABLE_INCLUDED */

View File

@ -211,6 +211,7 @@ static SYMBOL symbols[] = {
{ "ELSE", SYM(ELSE)},
{ "ELSEIF", SYM(ELSEIF_MARIADB_SYM)},
{ "ELSIF", SYM(ELSIF_MARIADB_SYM)},
{ "EMPTY", SYM(EMPTY_SYM)},
{ "ENABLE", SYM(ENABLE_SYM)},
{ "ENCLOSED", SYM(ENCLOSED)},
{ "END", SYM(END)},
@ -421,6 +422,7 @@ static SYMBOL symbols[] = {
{ "NATIONAL", SYM(NATIONAL_SYM)},
{ "NATURAL", SYM(NATURAL)},
{ "NCHAR", SYM(NCHAR_SYM)},
{ "NESTED", SYM(NESTED_SYM)},
{ "NEVER", SYM(NEVER_SYM)},
{ "NEW", SYM(NEW_SYM)},
{ "NEXT", SYM(NEXT_SYM)},
@ -455,6 +457,7 @@ static SYMBOL symbols[] = {
{ "OPTIONALLY", SYM(OPTIONALLY)},
{ "OR", SYM(OR_SYM)},
{ "ORDER", SYM(ORDER_SYM)},
{ "ORDINALITY", SYM(ORDINALITY_SYM)},
{ "OTHERS", SYM(OTHERS_MARIADB_SYM)},
{ "OUT", SYM(OUT_SYM)},
{ "OUTER", SYM(OUTER)},
@ -468,6 +471,7 @@ static SYMBOL symbols[] = {
{ "PAGE_CHECKSUM", SYM(PAGE_CHECKSUM_SYM)},
{ "PARSER", SYM(PARSER_SYM)},
{ "PARSE_VCOL_EXPR", SYM(PARSE_VCOL_EXPR_SYM)},
{ "PATH", SYM(PATH_SYM)},
{ "PERIOD", SYM(PERIOD_SYM)},
{ "PARTIAL", SYM(PARTIAL)},
{ "PARTITION", SYM(PARTITION_SYM)},
@ -758,6 +762,7 @@ static SYMBOL sql_functions[] = {
{ "GROUP_CONCAT", SYM(GROUP_CONCAT_SYM)},
{ "JSON_ARRAYAGG", SYM(JSON_ARRAYAGG_SYM)},
{ "JSON_OBJECTAGG", SYM(JSON_OBJECTAGG_SYM)},
{ "JSON_TABLE", SYM(JSON_TABLE_SYM)},
{ "LAG", SYM(LAG_SYM)},
{ "LEAD", SYM(LEAD_SYM)},
{ "MAX", SYM(MAX_SYM)},

View File

@ -1414,6 +1414,14 @@ void get_delayed_table_estimates(TABLE *table,
double *startup_cost)
{
Item_in_subselect *item= table->pos_in_table_list->jtbm_subselect;
Table_function_json_table *table_function=
table->pos_in_table_list->table_function;
if (table_function)
{
table_function->get_estimates(out_rows, scan_time, startup_cost);
return;
}
DBUG_ASSERT(item->engine->engine_type() ==
subselect_engine::HASH_SJ_ENGINE);
@ -1784,6 +1792,10 @@ static bool convert_subq_to_sj(JOIN *parent_join, Item_in_subselect *subq_pred)
tl->jtbm_subselect->fix_after_pullout(parent_lex, &dummy, true);
DBUG_ASSERT(dummy == tl->jtbm_subselect);
}
else if (tl->table_function)
{
tl->table_function->fix_after_pullout(tl, parent_lex, true);
}
SELECT_LEX *old_sl= tl->select_lex;
tl->select_lex= parent_join->select_lex;
for (TABLE_LIST *emb= tl->embedding;

View File

@ -637,6 +637,22 @@ void eliminate_tables(JOIN *join)
List_iterator<Item> it(join->fields_list);
while ((item= it++))
used_tables |= item->used_tables();
{
/*
Table function JSON_TABLE() can have references to other tables. Do not
eliminate the tables that JSON_TABLE() refers to.
Note: the JSON_TABLE itself cannot be eliminated as it doesn't
have unique keys.
*/
List_iterator<TABLE_LIST> it(join->select_lex->leaf_tables);
TABLE_LIST *tbl;
while ((tbl= it++))
{
if (tbl->table_function)
used_tables|= tbl->table_function->used_tables();
}
}
/* Add tables referred to from ORDER BY and GROUP BY lists */
ORDER *all_lists[]= { join->order, join->group_list};

View File

@ -247,9 +247,11 @@ void opt_trace_disable_if_no_tables_access(THD *thd, TABLE_LIST *tbl)
{
/*
Anonymous derived tables (as in
"SELECT ... FROM (SELECT ...)") don't have their grant.privilege set.
"SELECT ... FROM (SELECT ...)") and table functions
don't have their grant.privilege set.
*/
if (!t->is_anonymous_derived_table())
if (!t->is_anonymous_derived_table() &&
!t->table_function)
{
const GRANT_INFO backup_grant_info= t->grant;
Security_context *const backup_table_sctx= t->security_ctx;

View File

@ -7975,3 +7975,7 @@ ER_PK_INDEX_CANT_BE_IGNORED
eng "A primary key cannot be marked as IGNORE"
ER_BINLOG_UNSAFE_SKIP_LOCKED
eng "SKIP LOCKED makes this statement unsafe"
ER_JSON_TABLE_ERROR_ON_FIELD
eng "Field '%s' can't be set for JSON_TABLE '%s'."
ER_JSON_TABLE_ALIAS_REQUIRED
eng "Every table function must have an alias."

View File

@ -8150,6 +8150,14 @@ bool check_grant(THD *thd, privilege_t want_access, TABLE_LIST *tables,
if (!want_access)
continue; // ok
if (t_ref->table_function)
{
/* Table function doesn't need any privileges to be checked. */
t_ref->grant.privilege|= TMP_TABLE_ACLS;
t_ref->grant.want_privilege= NO_ACL;
continue;
}
if (!(~t_ref->grant.privilege & want_access) ||
t_ref->is_anonymous_derived_table() || t_ref->schema_table)
{

View File

@ -3684,6 +3684,14 @@ open_and_process_table(THD *thd, TABLE_LIST *tables, uint *counter, uint flags,
error= TRUE;
goto end;
}
if (tables->table_function)
{
if (!create_table_for_function(thd, tables))
error= TRUE;
goto end;
}
DBUG_PRINT("tcache", ("opening table: '%s'.'%s' item: %p",
tables->db.str, tables->table_name.str, tables));
(*counter)++;
@ -6454,7 +6462,10 @@ find_field_in_tables(THD *thd, Item_ident *item,
db= name_buff;
}
if (last_table)
if (first_table && first_table->select_lex &&
first_table->select_lex->end_lateral_table)
last_table= first_table->select_lex->end_lateral_table;
else if (last_table)
last_table= last_table->next_name_resolution_table;
for (; cur_table != last_table ;

View File

@ -7723,5 +7723,9 @@ public:
extern THD_list server_threads;
void setup_tmp_table_column_bitmaps(TABLE *table, uchar *bitmaps);
void
setup_tmp_table_column_bitmaps(TABLE *table, uchar *bitmaps, uint field_count);
#endif /* MYSQL_SERVER */
#endif /* SQL_CLASS_INCLUDED */

View File

@ -1635,6 +1635,9 @@ void Explain_table_access::tag_to_json(Json_writer *writer, enum explain_extra_t
case ET_DISTINCT:
writer->add_member("distinct").add_bool(true);
break;
case ET_TABLE_FUNCTION:
writer->add_member("table_function").add_str("json_table");
break;
default:
DBUG_ASSERT(0);
@ -2027,6 +2030,9 @@ void Explain_table_access::append_tag_name(String *str, enum explain_extra_tag t
if (loose_scan_is_scanning)
str->append(" (scanning)");
break;
case ET_TABLE_FUNCTION:
str->append("Table function: json_table");
break;
}
default:
str->append(extra_tag_text[tag]);

View File

@ -550,6 +550,7 @@ enum explain_extra_tag
ET_CONST_ROW_NOT_FOUND,
ET_UNIQUE_ROW_NOT_FOUND,
ET_IMPOSSIBLE_ON_CONDITION,
ET_TABLE_FUNCTION,
ET_total
};

View File

@ -3840,6 +3840,12 @@ void LEX::cleanup_lex_after_parse_error(THD *thd)
thd->lex->sphead= NULL;
}
}
/*
json_table must be NULL before the query.
Didn't want to overload LEX::start, it's enough to put it here.
*/
thd->lex->json_table= 0;
}
/*
@ -3927,7 +3933,7 @@ void Query_tables_list::destroy_query_tables_list()
LEX::LEX()
: explain(NULL), result(0), part_info(NULL), arena_for_set_stmt(0), mem_root_for_set_stmt(0),
option_type(OPT_DEFAULT), context_analysis_only(0), sphead(0),
json_table(NULL), option_type(OPT_DEFAULT), context_analysis_only(0), sphead(0),
default_used(0), is_lex_started(0), limit_rows_examined_cnt(ULONGLONG_MAX)
{
@ -5054,6 +5060,7 @@ void st_select_lex::remap_tables(TABLE_LIST *derived, table_map map,
uint tablenr, SELECT_LEX *parent_lex)
{
bool first_table= TRUE;
bool has_table_function= FALSE;
TABLE_LIST *tl;
table_map first_map;
uint first_tablenr;
@ -5095,6 +5102,19 @@ void st_select_lex::remap_tables(TABLE_LIST *derived, table_map map,
emb && emb->select_lex == old_sl;
emb= emb->embedding)
emb->select_lex= parent_lex;
if (tl->table_function)
has_table_function= TRUE;
}
if (has_table_function)
{
ti.rewind();
while ((tl= ti++))
{
if (tl->table_function)
tl->table_function->fix_after_pullout(tl, parent_lex, true);
}
}
}
@ -5266,6 +5286,9 @@ void SELECT_LEX::update_used_tables()
left_expr->walk(&Item::update_table_bitmaps_processor, FALSE, NULL);
}
if (tl->table_function)
tl->table_function->update_used_tables();
embedding= tl->embedding;
while (embedding)
{

View File

@ -34,6 +34,7 @@
#include "sql_tvc.h"
#include "item.h"
#include "sql_limit.h" // Select_limit_counters
#include "json_table.h" // Json_table_column
#include "sql_schema.h"
/* Used for flags of nesting constructs */
@ -454,6 +455,7 @@ enum enum_drop_mode
#define TL_OPTION_IGNORE_LEAVES 4
#define TL_OPTION_ALIAS 8
#define TL_OPTION_SEQUENCE 16
#define TL_OPTION_TABLE_FUNCTION 32
typedef List<Item> List_item;
typedef Mem_root_array<ORDER*, true> Group_list_ptrs;
@ -1182,6 +1184,8 @@ public:
enum leaf_list_state {UNINIT, READY, SAVED};
enum leaf_list_state prep_leaf_list_state;
uint insert_tables;
// Last table for LATERAL join, used by table functions
TABLE_LIST *end_lateral_table;
st_select_lex *merged_into; /* select which this select is merged into */
/* (not 0 only for views/derived tables) */
@ -1405,7 +1409,8 @@ public:
enum_mdl_type mdl_type= MDL_SHARED_READ,
List<Index_hint> *hints= 0,
List<String> *partition_names= 0,
LEX_STRING *option= 0);
LEX_STRING *option= 0,
Table_function_json_table *tfunc= 0);
TABLE_LIST* get_table_list();
bool init_nested_join(THD *thd);
TABLE_LIST *end_nested_join(THD *thd);
@ -1444,8 +1449,8 @@ public:
ha_rows get_limit();
friend struct LEX;
st_select_lex() : group_list_ptrs(NULL), braces(0), automatic_brackets(0),
n_sum_items(0), n_child_sum_items(0)
st_select_lex() : group_list_ptrs(NULL), end_lateral_table(NULL), braces(0),
automatic_brackets(0), n_sum_items(0), n_child_sum_items(0)
{}
void make_empty_select()
{
@ -3313,6 +3318,7 @@ public:
SQL_I_List<ORDER> proc_list;
SQL_I_List<TABLE_LIST> auxiliary_table_list, save_list;
Column_definition *last_field;
Table_function_json_table *json_table;
Item_sum *in_sum_func;
udf_func udf;
HA_CHECK_OPT check_opt; // check/repair options

View File

@ -7104,6 +7104,9 @@ check_table_access(THD *thd, privilege_t requirements, TABLE_LIST *tables,
if (table_ref->is_anonymous_derived_table())
continue;
if (table_ref->table_function)
continue;
if (table_ref->sequence)
{
/* We want to have either SELECT or INSERT rights to sequences depending
@ -8159,7 +8162,8 @@ TABLE_LIST *st_select_lex::add_table_to_list(THD *thd,
enum_mdl_type mdl_type,
List<Index_hint> *index_hints_arg,
List<String> *partition_names,
LEX_STRING *option)
LEX_STRING *option,
Table_function_json_table *tfunc)
{
TABLE_LIST *ptr;
TABLE_LIST *UNINIT_VAR(previous_table_ref); /* The table preceding the current one. */
@ -8184,6 +8188,7 @@ TABLE_LIST *st_select_lex::add_table_to_list(THD *thd,
}
if (unlikely(table->is_derived_table() == FALSE && table->db.str &&
!(table_options & TL_OPTION_TABLE_FUNCTION) &&
check_db_name((LEX_STRING*) &table->db)))
{
my_error(ER_WRONG_DB_NAME, MYF(0), table->db.str);
@ -8227,6 +8232,7 @@ TABLE_LIST *st_select_lex::add_table_to_list(THD *thd,
ptr->table_name= table->table;
ptr->lock_type= lock_type;
ptr->table_function= tfunc;
ptr->updating= MY_TEST(table_options & TL_OPTION_UPDATING);
/* TODO: remove TL_OPTION_FORCE_INDEX as it looks like it's not used */
ptr->force_index= MY_TEST(table_options & TL_OPTION_FORCE_INDEX);
@ -8271,7 +8277,9 @@ TABLE_LIST *st_select_lex::add_table_to_list(THD *thd,
{
if (unlikely(!my_strcasecmp(table_alias_charset, alias_str.str,
tables->alias.str) &&
!cmp(&ptr->db, &tables->db) && ! tables->sequence))
(tables->table_function || ptr->table_function ||
!cmp(&ptr->db, &tables->db)) &&
!tables->sequence))
{
my_error(ER_NONUNIQ_TABLE, MYF(0), alias_str.str); /* purecov: tested */
DBUG_RETURN(0); /* purecov: tested */

View File

@ -1242,6 +1242,14 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num,
enum_parsing_place save_place=
thd->lex->current_select->context_analysis_place;
thd->lex->current_select->context_analysis_place= SELECT_LIST;
for (TABLE_LIST *tbl= tables_list; tbl; tbl= tbl->next_local)
{
if (tbl->table_function &&
tbl->table_function->setup(thd, tbl, select_lex_arg))
DBUG_RETURN(-1);
}
if (setup_fields(thd, ref_ptrs, fields_list, MARK_COLUMNS_READ,
&all_fields, &select_lex->pre_fix, 1))
DBUG_RETURN(-1);
@ -12753,6 +12761,10 @@ uint check_join_cache_usage(JOIN_TAB *tab,
!join->allowed_outer_join_with_cache)
goto no_join_cache;
if (tab->table->pos_in_table_list->table_function &&
!tab->table->pos_in_table_list->table_function->join_cache_allowed())
goto no_join_cache;
/*
Non-linked join buffers can't guarantee one match
*/
@ -16531,7 +16543,7 @@ simplify_joins(JOIN *join, List<TABLE_LIST> *join_list, COND *conds, bool top,
if (table->outer_join && !table->embedding && table->table)
table->table->maybe_null= FALSE;
table->outer_join= 0;
if (!(straight_join || table->straight))
if (!(straight_join || table->straight || table->table_function))
{
table->dep_tables= 0;
TABLE_LIST *embedding= table->embedding;
@ -26854,6 +26866,9 @@ bool JOIN_TAB::save_explain_data(Explain_table_access *eta,
!((QUICK_ROR_INTERSECT_SELECT*)cur_quick)->need_to_fetch_row)
key_read=1;
if (table_list->table_function)
eta->push_extra(ET_TABLE_FUNCTION);
if (info)
{
eta->push_extra(info);
@ -27690,6 +27705,14 @@ void TABLE_LIST::print(THD *thd, table_map eliminated_tables, String *str,
cmp_name= table_name.str;
}
}
else if (table_function)
{
/* A table function. */
(void) table_function->print(thd, this, str, query_type);
str->append(' ');
append_identifier(thd, str, &alias);
cmp_name= alias.str;
}
else
{
// A normal table

View File

@ -2448,7 +2448,6 @@ bool instantiate_tmp_table(TABLE *table, KEY *keyinfo,
TMP_ENGINE_COLUMNDEF **recinfo,
ulonglong options);
bool open_tmp_table(TABLE *table);
void setup_tmp_table_column_bitmaps(TABLE *table, uchar *bitmaps);
double prev_record_reads(const POSITION *positions, uint idx, table_map found_ref);
void fix_list_after_tbl_changes(SELECT_LEX *new_parent, List<TABLE_LIST> *tlist);
double get_tmp_table_lookup_cost(THD *thd, double row_count, uint row_size);

View File

@ -522,7 +522,7 @@ bool mysql_create_view(THD *thd, TABLE_LIST *views,
{
/* is this table temporary and is not view? */
if (tbl->table->s->tmp_table != NO_TMP_TABLE && !tbl->view &&
!tbl->schema_table)
!tbl->schema_table && !tbl->table_function)
{
my_error(ER_VIEW_SELECT_TMPTABLE, MYF(0), tbl->alias.str);
res= TRUE;

View File

@ -68,6 +68,7 @@
#include "sql_sequence.h"
#include "my_base.h"
#include "sql_type_json.h"
#include "json_table.h"
/* this is to get the bison compilation windows warnings out */
#ifdef _MSC_VER
@ -195,6 +196,18 @@ void _CONCAT_UNDERSCORED(turn_parser_debug_on,yyparse)()
MYSQL_YYABORT; \
} while(0)
#define set_collation(X) \
do { \
if (X) \
{ \
if (unlikely(Lex->charset && !my_charset_same(Lex->charset,X))) \
my_yyabort_error((ER_COLLATION_CHARSET_MISMATCH, MYF(0), \
X->name,Lex->charset->csname)); \
Lex->charset= X; \
} \
} while(0)
%}
%union {
int num;
@ -219,6 +232,7 @@ void _CONCAT_UNDERSCORED(turn_parser_debug_on,yyparse)()
Lex_for_loop_st for_loop;
Lex_for_loop_bounds_st for_loop_bounds;
Lex_trim_st trim;
Json_table_column::On_response json_on_response;
vers_history_point_t vers_history_point;
struct
{
@ -506,6 +520,7 @@ End SQL_MODE_ORACLE_SPECIFIC */
%token <kwd> ELSEIF_MARIADB_SYM
%token <kwd> ELSE /* SQL-2003-R */
%token <kwd> ELSIF_ORACLE_SYM /* PLSQL-R */
%token <kwd> EMPTY_SYM /* SQL-2016-R */
%token <kwd> ENCLOSED
%token <kwd> ESCAPED
%token <kwd> EXCEPT_SYM /* SQL-2003-R */
@ -524,6 +539,7 @@ End SQL_MODE_ORACLE_SPECIFIC */
%token <kwd> GROUP_CONCAT_SYM
%token <rwd> JSON_ARRAYAGG_SYM
%token <rwd> JSON_OBJECTAGG_SYM
%token <rwd> JSON_TABLE_SYM
%token <kwd> GROUP_SYM /* SQL-2003-R */
%token <kwd> HAVING /* SQL-2003-R */
%token <kwd> HOUR_MICROSECOND_SYM
@ -582,6 +598,7 @@ End SQL_MODE_ORACLE_SPECIFIC */
%token <kwd> MOD_SYM /* SQL-2003-N */
%token <kwd> NATURAL /* SQL-2003-R */
%token <kwd> NEG
%token <kwd> NESTED_SYM /* SQL-2003-N */
%token <kwd> NOT_SYM /* SQL-2003-R */
%token <kwd> NO_WRITE_TO_BINLOG
%token <kwd> NOW_SYM
@ -593,6 +610,7 @@ End SQL_MODE_ORACLE_SPECIFIC */
%token <kwd> OPTIMIZE
%token <kwd> OPTIONALLY
%token <kwd> ORDER_SYM /* SQL-2003-R */
%token <kwd> ORDINALITY_SYM /* SQL-2003-N */
%token <kwd> OR_SYM /* SQL-2003-R */
%token <kwd> OTHERS_ORACLE_SYM /* SQL-2011-N, PLSQL-R */
%token <kwd> OUTER
@ -603,6 +621,7 @@ End SQL_MODE_ORACLE_SPECIFIC */
%token <kwd> PAGE_CHECKSUM_SYM
%token <kwd> PARSE_VCOL_EXPR_SYM
%token <kwd> PARTITION_SYM /* SQL-2003-R */
%token <kwd> PATH_SYM /* SQL-2003-N */
%token <kwd> PERCENTILE_CONT_SYM
%token <kwd> PERCENTILE_DISC_SYM
%token <kwd> PERCENT_RANK_SYM
@ -1300,6 +1319,7 @@ End SQL_MODE_ORACLE_SPECIFIC */
%type <lex_string_with_metadata>
TEXT_STRING
NCHAR_STRING
json_text_literal
%type <lex_str_ptr>
opt_table_alias_clause
@ -1359,6 +1379,8 @@ End SQL_MODE_ORACLE_SPECIFIC */
%type <sp_handler> sp_handler
%type <json_on_response> json_on_response
%type <Lex_field_type> field_type field_type_all
qualified_field_type
field_type_numeric
@ -1366,6 +1388,7 @@ End SQL_MODE_ORACLE_SPECIFIC */
field_type_lob
field_type_temporal
field_type_misc
json_table_field_type
%type <Lex_dyncol_type> opt_dyncol_type dyncol_type
numeric_dyncol_type temporal_dyncol_type string_dyncol_type
@ -1529,7 +1552,7 @@ End SQL_MODE_ORACLE_SPECIFIC */
table_primary_derived table_primary_derived_opt_parens
derived_table_list table_reference_list_parens
nested_table_reference_list join_table_parens
update_table_list
update_table_list table_function
%type <date_time_type> date_time_type;
%type <interval> interval
@ -1684,6 +1707,9 @@ End SQL_MODE_ORACLE_SPECIFIC */
opt_delete_gtid_domain
asrow_attribute
opt_constraint_no_id
json_table_columns_clause json_table_columns_list json_table_column
json_table_column_type json_opt_on_empty_or_error
json_on_error_response json_on_empty_response
%type <NONE> call sp_proc_stmts sp_proc_stmts1 sp_proc_stmt
%type <NONE> sp_if_then_statements sp_case_then_statements
@ -9833,7 +9859,7 @@ column_default_non_parenthesized_expr:
| variable
| sum_expr
{
if (!Lex->select_stack_top)
if (!Lex->select_stack_top || Lex->json_table)
{
my_error(ER_INVALID_GROUP_FUNC_USE, MYF(0));
MYSQL_YYABORT;
@ -11497,10 +11523,200 @@ table_ref:
}
;
json_text_literal:
TEXT_STRING
{
Lex->json_table->m_text_literal_cs= NULL;
}
| NCHAR_STRING
{
Lex->json_table->m_text_literal_cs= national_charset_info;
}
| UNDERSCORE_CHARSET TEXT_STRING
{
Lex->json_table->m_text_literal_cs= $1;
$$= $2;
}
;
join_table_list:
derived_table_list { MYSQL_YYABORT_UNLESS($$=$1); }
;
json_table_columns_clause:
COLUMNS '(' json_table_columns_list ')'
{}
;
json_table_columns_list:
json_table_column
| json_table_columns_list ',' json_table_column
{}
;
json_table_column:
ident
{
LEX *lex=Lex;
Create_field *f= new (thd->mem_root) Create_field();
if (unlikely(check_string_char_length(&$1, 0, NAME_CHAR_LEN,
system_charset_info, 1)))
my_yyabort_error((ER_TOO_LONG_IDENT, MYF(0), $1.str));
lex->json_table->m_cur_json_table_column=
new (thd->mem_root) Json_table_column(f,
lex->json_table->get_cur_nested_path());
if (unlikely(!f ||
!lex->json_table->m_cur_json_table_column))
MYSQL_YYABORT;
lex->init_last_field(f, &$1, NULL);
}
json_table_column_type
{
LEX *lex=Lex;
if (unlikely(lex->json_table->
m_cur_json_table_column->m_field->check(thd)))
MYSQL_YYABORT;
lex->json_table->m_columns.push_back(
lex->json_table->m_cur_json_table_column, thd->mem_root);
}
| NESTED_SYM PATH_SYM json_text_literal
{
LEX *lex=Lex;
Json_table_nested_path *np= new (thd->mem_root)
Json_table_nested_path();
np->set_path(thd, $3);
lex->json_table->start_nested_path(np);
}
json_table_columns_clause
{
LEX *lex=Lex;
lex->json_table->end_nested_path();
}
;
json_table_column_type:
FOR_SYM ORDINALITY_SYM
{
Lex_field_type_st type;
type.set_handler_length_flags(&type_handler_slong, 0, 0);
Lex->last_field->set_attributes(thd, type, Lex->charset,
COLUMN_DEFINITION_TABLE_FIELD);
Lex->json_table->m_cur_json_table_column->
set(Json_table_column::FOR_ORDINALITY);
}
| json_table_field_type PATH_SYM json_text_literal
json_opt_on_empty_or_error
{
Lex->last_field->set_attributes(thd, $1, Lex->charset,
COLUMN_DEFINITION_TABLE_FIELD);
if (Lex->json_table->m_cur_json_table_column->
set(thd, Json_table_column::PATH, $3))
{
MYSQL_YYABORT;
}
}
| json_table_field_type EXISTS PATH_SYM json_text_literal
{
Lex->last_field->set_attributes(thd, $1, Lex->charset,
COLUMN_DEFINITION_TABLE_FIELD);
Lex->json_table->m_cur_json_table_column->
set(thd, Json_table_column::EXISTS_PATH, $4);
}
;
json_table_field_type:
field_type_numeric
| field_type_temporal
| field_type_string opt_collate
{
set_collation($2);
}
| field_type_lob opt_collate
{
set_collation($2);
}
;
json_opt_on_empty_or_error:
/* none */
{}
| json_on_error_response
| json_on_error_response json_on_empty_response
| json_on_empty_response
| json_on_empty_response json_on_error_response
;
json_on_response:
ERROR_SYM
{
$$.m_response= Json_table_column::RESPONSE_ERROR;
}
| NULL_SYM
{
$$.m_response= Json_table_column::RESPONSE_NULL;
}
| DEFAULT json_text_literal
{
$$.m_response= Json_table_column::RESPONSE_DEFAULT;
$$.m_default= $2;
Lex->json_table->m_cur_json_table_column->m_defaults_cs=
thd->variables.collation_connection;
}
;
json_on_error_response:
json_on_response ON ERROR_SYM
{
Lex->json_table->m_cur_json_table_column->m_on_error= $1;
}
;
json_on_empty_response:
json_on_response ON EMPTY_SYM
{
Lex->json_table->m_cur_json_table_column->m_on_empty= $1;
}
;
table_function:
JSON_TABLE_SYM '(' expr ','
{
Table_function_json_table *jt=
new (thd->mem_root) Table_function_json_table($3);
if (unlikely(!jt))
MYSQL_YYABORT;
Lex->json_table= jt;
}
json_text_literal json_table_columns_clause ')' opt_table_alias_clause
{
SELECT_LEX *sel= Select;
if (unlikely($9 == NULL))
{
/* Alias is not optional. */
my_error(ER_JSON_TABLE_ALIAS_REQUIRED, MYF(0));
MYSQL_YYABORT;
}
if (unlikely(Lex->json_table->m_nested_path.set_path(thd, $6)))
MYSQL_YYABORT;
sel->table_join_options= 0;
if (!($$= Select->add_table_to_list(thd,
new (thd->mem_root) Table_ident(thd, &empty_clex_str,
$9, TRUE),
NULL,
Select->get_table_join_options() |
TL_OPTION_TABLE_FUNCTION,
YYPS->m_lock_type,
YYPS->m_mdl_type,
0,0,0, Lex->json_table)))
MYSQL_YYABORT;
Lex->json_table= 0;
}
;
/*
The ODBC escape syntax for Outer Join is: '{' OJ join_table '}'
The parser does not define OJ as a token, any ident is accepted
@ -11708,6 +11924,7 @@ table_factor:
$$= $1;
}
| table_reference_list_parens { $$= $1; }
| table_function { $$= $1; }
;
table_primary_ident_opt_parens:
@ -15646,6 +15863,7 @@ keyword_sp_var_and_label:
| DYNAMIC_SYM
| ELSEIF_ORACLE_SYM
| ELSIF_MARIADB_SYM
| EMPTY_SYM
| ENDS_SYM
| ENGINE_SYM
| ENGINES_SYM
@ -15752,6 +15970,7 @@ keyword_sp_var_and_label:
| MYSQL_SYM
| MYSQL_ERRNO_SYM
| NAME_SYM
| NESTED_SYM
| NEVER_SYM
| NEXT_SYM %prec PREC_BELOW_CONTRACTION_TOKEN2
| NEXTVAL_SYM
@ -15771,6 +15990,7 @@ keyword_sp_var_and_label:
| ONE_SYM
| ONLINE_SYM
| ONLY_SYM
| ORDINALITY_SYM
| OVERLAPS_SYM
| PACKAGE_MARIADB_SYM
| PACK_KEYS_SYM
@ -15778,6 +15998,7 @@ keyword_sp_var_and_label:
| PARTIAL
| PARTITIONING_SYM
| PARTITIONS_SYM
| PATH_SYM
| PERSISTENT_SYM
| PHASE_SYM
| PLUGIN_SYM

View File

@ -6968,7 +6968,7 @@ const char *Field_iterator_table_ref::get_table_name()
DBUG_ASSERT(!strcmp(table_ref->table_name.str,
table_ref->table->s->table_name.str) ||
table_ref->schema_table);
table_ref->schema_table || table_ref->table_function);
return table_ref->table_name.str;
}
@ -6987,7 +6987,8 @@ const char *Field_iterator_table_ref::get_db_name()
*/
DBUG_ASSERT(!cmp(&table_ref->db, &table_ref->table->s->db) ||
(table_ref->schema_table &&
is_infoschema_db(&table_ref->table->s->db)));
is_infoschema_db(&table_ref->table->s->db)) ||
table_ref->table_function);
return table_ref->db.str;
}
@ -8180,7 +8181,8 @@ bool TABLE::is_filled_at_execution()
*/
return MY_TEST(!pos_in_table_list ||
pos_in_table_list->jtbm_subselect ||
pos_in_table_list->is_active_sjm());
pos_in_table_list->is_active_sjm() ||
pos_in_table_list->table_function);
}

View File

@ -63,6 +63,7 @@ class Range_rowid_filter_cost_info;
class derived_handler;
class Pushdown_derived;
struct Name_resolution_context;
class Table_function_json_table;
/*
Used to identify NESTED_JOIN structures within a join (applicable only to
@ -2209,6 +2210,7 @@ struct TABLE_LIST
const char *option; /* Used by cache index */
Item *on_expr; /* Used with outer join */
Name_resolution_context *on_context; /* For ON expressions */
Table_function_json_table *table_function; /* If it's the table function. */
Item *sj_on_expr;
/*
@ -2601,7 +2603,7 @@ struct TABLE_LIST
void cleanup_items();
bool placeholder()
{
return derived || view || schema_table || !table;
return derived || view || schema_table || !table || table_function;
}
void print(THD *thd, table_map eliminated_tables, String *str,
enum_query_type query_type);