mirror of
https://github.com/MariaDB/server.git
synced 2025-01-29 02:05:57 +01:00
MDEV-17399: JSON_TABLE: Fix the problem with cross-nested-join dependency
Fix for for the problem with - Cross-outer-join dependency - dead-end join prefix - join order pruning See the comments in the patch for detailed description
This commit is contained in:
parent
e9fd327ee3
commit
2f650fb955
5 changed files with 182 additions and 2 deletions
|
@ -462,5 +462,34 @@ select min(x) from json_table('[]', '$' COLUMNS(x FOR ORDINALITY)) a;
|
|||
min(x)
|
||||
1
|
||||
#
|
||||
# End of 10.5 tests
|
||||
# Test for the problem with
|
||||
# - Cross-outer-join dependency
|
||||
# - dead-end join prefix
|
||||
# - join order pruning
|
||||
#
|
||||
create table t20 (a int not null);
|
||||
create table t21 (a int not null primary key, js varchar(100));
|
||||
insert into t20 select seq from seq_1_to_100;
|
||||
insert into t21 select a, '{"a":100}' from t20;
|
||||
create table t31(a int);
|
||||
create table t32(b int);
|
||||
insert into t31 values (1);
|
||||
insert into t32 values (1);
|
||||
explain
|
||||
select
|
||||
t20.a, jt1.ab
|
||||
from
|
||||
t20
|
||||
left join t21 on t20.a=t21.a
|
||||
join
|
||||
(t31 left join (t32 join JSON_TABLE(t21.js,'$' COLUMNS (ab INT PATH '$.a')) AS jt1) on t31.a<3);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t31 system NULL NULL NULL NULL 1
|
||||
1 SIMPLE t20 ALL NULL NULL NULL NULL 100
|
||||
1 SIMPLE t21 eq_ref PRIMARY PRIMARY 4 test.t20.a 1
|
||||
1 SIMPLE t32 ALL NULL NULL NULL NULL 1 Using where
|
||||
1 SIMPLE jt1 ALL NULL NULL NULL NULL 40 Table function: json_table
|
||||
drop table t20,t21,t31,t32;
|
||||
#
|
||||
# End of 10.6 tests
|
||||
#
|
||||
|
|
|
@ -1,3 +1,5 @@
|
|||
--source include/have_sequence.inc
|
||||
|
||||
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;
|
||||
|
@ -347,5 +349,34 @@ 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 # Test for the problem with
|
||||
--echo # - Cross-outer-join dependency
|
||||
--echo # - dead-end join prefix
|
||||
--echo # - join order pruning
|
||||
--echo #
|
||||
|
||||
create table t20 (a int not null);
|
||||
create table t21 (a int not null primary key, js varchar(100));
|
||||
|
||||
insert into t20 select seq from seq_1_to_100;
|
||||
insert into t21 select a, '{"a":100}' from t20;
|
||||
|
||||
create table t31(a int);
|
||||
create table t32(b int);
|
||||
insert into t31 values (1);
|
||||
insert into t32 values (1);
|
||||
|
||||
explain
|
||||
select
|
||||
t20.a, jt1.ab
|
||||
from
|
||||
t20
|
||||
left join t21 on t20.a=t21.a
|
||||
join
|
||||
(t31 left join (t32 join JSON_TABLE(t21.js,'$' COLUMNS (ab INT PATH '$.a')) AS jt1) on t31.a<3);
|
||||
|
||||
drop table t20,t21,t31,t32;
|
||||
|
||||
--echo #
|
||||
--echo # End of 10.6 tests
|
||||
--echo #
|
||||
|
|
|
@ -1284,3 +1284,117 @@ void Table_function_json_table::fix_after_pullout(TABLE_LIST *sql_table,
|
|||
}
|
||||
|
||||
|
||||
/*
|
||||
@brief
|
||||
Recursively make all tables in the join_list also depend on deps.
|
||||
*/
|
||||
|
||||
static void add_extra_deps(List<TABLE_LIST> *join_list, table_map deps)
|
||||
{
|
||||
TABLE_LIST *table;
|
||||
List_iterator<TABLE_LIST> li(*join_list);
|
||||
while ((table= li++))
|
||||
{
|
||||
table->dep_tables |= deps;
|
||||
NESTED_JOIN *nested_join;
|
||||
if ((nested_join= table->nested_join))
|
||||
{
|
||||
// set the deps inside, too
|
||||
add_extra_deps(&nested_join->join_list, deps);
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
@brief
|
||||
Add extra dependencies implied by table functions so that the join
|
||||
optimizer does not construct "dead-end" join prefixes.
|
||||
|
||||
@detail
|
||||
There are two kinds of limitations on join order:
|
||||
1A. Outer joins require that inner tables follow outer.
|
||||
1B. Tables within a join nest must be present in the join order
|
||||
"without interleaving". See check_interleaving_with_nj for details.
|
||||
|
||||
2. Table function argument may refer to *any* table that precedes the
|
||||
current table in the query text. The table maybe outside of the current
|
||||
nested join and/or inside another nested join.
|
||||
|
||||
@example
|
||||
|
||||
select ...
|
||||
from
|
||||
t20 left join t21 on t20.a=t21.a
|
||||
join
|
||||
(t31 left join (t32 join
|
||||
JSON_TABLE(t21.js,
|
||||
'$' COLUMNS (ab INT PATH '$.a')) AS jt
|
||||
) on t31.a<3
|
||||
)
|
||||
|
||||
Here, jt's argument refers to t21.
|
||||
|
||||
Table dependencies are:
|
||||
t21 -> t20
|
||||
t32 -> t31
|
||||
jt -> t21 t31 (also indirectly depends on t20 through t21)
|
||||
|
||||
This allows to construct a "dead-end" join prefix, like:
|
||||
|
||||
t31, t32
|
||||
|
||||
Here, "no interleaving" rule requires the next table to be jt, but we
|
||||
can't add it, because it depends on t21 which is not in the join prefix.
|
||||
|
||||
@end example
|
||||
|
||||
Dead-end join prefixes do not work with join prefix pruning done for
|
||||
@@optimizer_prune_level: it is possible that all non-dead-end prefixes are
|
||||
pruned away.
|
||||
|
||||
The solution is as follows: if there is an outer join that contains
|
||||
(directly on indirectly) a table function JT which has a reference JREF
|
||||
outside of the outer join:
|
||||
|
||||
left join ( T_I ... json_table(JREF, ...) as JT ...)
|
||||
|
||||
then make *all* tables T_I also dependent on outside references in JREF.
|
||||
This way, the optimizer will put table T_I into the join prefix only when
|
||||
JT can be put there as well, and "dead-end" prefixes will not be built.
|
||||
|
||||
@param join_list List of tables to process. Initial invocation should
|
||||
supply the JOIN's top-level table list.
|
||||
@param nest_tables Bitmap of all tables in the join list.
|
||||
|
||||
@return Bitmap of all outside references that tables in join_list have
|
||||
*/
|
||||
|
||||
table_map add_table_function_dependencies(List<TABLE_LIST> *join_list,
|
||||
table_map nest_tables)
|
||||
{
|
||||
TABLE_LIST *table;
|
||||
table_map res= 0;
|
||||
List_iterator<TABLE_LIST> li(*join_list);
|
||||
|
||||
// Recursively compute extra dependencies
|
||||
while ((table= li++))
|
||||
{
|
||||
NESTED_JOIN *nested_join;
|
||||
if ((nested_join= table->nested_join))
|
||||
{
|
||||
res |= add_table_function_dependencies(&nested_join->join_list,
|
||||
nested_join->used_tables);
|
||||
}
|
||||
else if (table->table_function)
|
||||
res |= table->dep_tables;
|
||||
}
|
||||
res= res & ~nest_tables & ~PSEUDO_TABLE_BITS;
|
||||
// Then, make all "peers" have them:
|
||||
if (res)
|
||||
add_extra_deps(join_list, res);
|
||||
|
||||
return res;
|
||||
}
|
||||
|
||||
|
||||
|
|
|
@ -252,5 +252,8 @@ private:
|
|||
|
||||
TABLE *create_table_for_function(THD *thd, TABLE_LIST *sql_table);
|
||||
|
||||
table_map add_table_function_dependencies(List<TABLE_LIST> *join_list,
|
||||
table_map nest_tables);
|
||||
|
||||
#endif /* JSON_TABLE_INCLUDED */
|
||||
|
||||
|
|
|
@ -1924,6 +1924,9 @@ JOIN::optimize_inner()
|
|||
|
||||
/* Convert all outer joins to inner joins if possible */
|
||||
conds= simplify_joins(this, join_list, conds, TRUE, FALSE);
|
||||
|
||||
add_table_function_dependencies(join_list, table_map(-1));
|
||||
|
||||
if (thd->is_error() || select_lex->save_leaf_tables(thd))
|
||||
{
|
||||
if (arena)
|
||||
|
|
Loading…
Add table
Reference in a new issue