MDEV-25158 Segfault on INTERSECT ALL with UNION in Oracle mode

Oracle mode has different set operator precedence and handling (not by
standard). In Oracle mode the below test case is handled as-is, in
plain order from left to right. In MariaDB default mode follows SQL
standard and makes INTERSECT prioritized, so UNION is taken from
derived table which is INTERSECT result (here and below the same
applies for EXCEPT).

Non-distinct set operator (UNION ALL/INTERSECT ALL) works via unique
key release but it can be done only once. We cannot add index to
non-empty heap table (see heap_enable_indexes()). So every UNION ALL
before rightmost UNION DISTINCT works as UNION DISTINCT. That is
common syntax, MySQL, MSSQL and Oracle work that way.

There is union_distinct property which indicates the rightmost
distinct UNION (at least, so the algorithm works simple: it releases
the unique key after union_distinct in the loop
(st_select_lex_unit::exec()).

INTERSECT ALL code (implemented by MDEV-18844 in a896beb) does not
know about Oracle mode and treats union_distinct as the last
operation, that's why it releases unique key on union_distinct
operation. INTERSECT ALL requires unique key for it to work, so before
any INTERSECT ALL unique key must not be released (see
select_unit_ext::send_data()).

The patch tweaks INTERSECT ALL code for Oracle mode. In
disable_index_if_needed() it does not allow unique key release before
the last operation and it allows unfold on the last operation. Test
case with UNION DISTINCT following INTERSECT ALL at least does not
include invalid data, but in fact the whole INTERSECT ALL code could
be refactored for better semantical triggers.

The patch fixes typo in st_select_lex_unit::prepare() where
have_except_all_or_intersect_all masked eponymous data member which
wrongly triggered unique key release in st_select_lex_unit::prepare().

The patch fixes unknown error in case ha_disable_indexes() fails.

Note: optimize_bag_operation() does some operator substitutions, but
it does not run under PS. So if there is difference in test with --ps
that means non-optimized (have_except_all_or_intersect_all == true)
code path is not good.

Note 2: VIEW is stored and executed in normal mode (see
Sql_mode_save_for_frm_handling) hence when SELECT order is different
in Oracle mode (defined by parsed_select_expr_cont()) it must be
covered by --disable_view_protocol.
This commit is contained in:
Aleksey Midenkov
2025-05-28 11:28:16 +03:00
parent e021a61b6f
commit 0b2434d2e9
3 changed files with 212 additions and 11 deletions

View File

@ -920,3 +920,113 @@ NULL INTERSECT RESULT <intersect2,3> ALL NULL NULL NULL NULL NULL NULL
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 4 union all /* select#4 */ select `__4`.`a` AS `a` from (/* select#2 */ select `test`.`t2`.`a` AS `a` from `test`.`t2` where `test`.`t2`.`a` < 5 intersect all /* select#3 */ select `test`.`t3`.`a` AS `a` from `test`.`t3` where `test`.`t3`.`a` < 5) `__4`
drop table t1,t2,t3;
#
# MDEV-25158 Segfault on INTERSECT ALL with UNION in Oracle mode
#
create table t3 (x int);
create table u3 (x int);
create table i3 (x int);
explain SELECT * from t3 union select * from u3 intersect all select * from i3;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t3 system NULL NULL NULL NULL 0 Const row not found
4 UNION <derived2> ALL NULL NULL NULL NULL 2
2 DERIVED NULL NULL NULL NULL NULL NULL NULL no matching row in const table
3 INTERSECT NULL NULL NULL NULL NULL NULL NULL no matching row in const table
NULL INTERSECT RESULT <intersect2,3> ALL NULL NULL NULL NULL NULL
NULL UNION RESULT <union1,4> ALL NULL NULL NULL NULL NULL
set sql_mode= 'oracle';
explain SELECT * from t3 union select * from u3 intersect all select * from i3;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t3 system NULL NULL NULL NULL 0 Const row not found
2 UNION u3 system NULL NULL NULL NULL 0 Const row not found
3 INTERSECT i3 system NULL NULL NULL NULL 0 Const row not found
NULL UNIT RESULT <unit1,2,3> ALL NULL NULL NULL NULL NULL
select * from t3 union select * from u3 intersect select * from i3;
x
SELECT * from t3 union select * from u3 intersect all select * from i3;
x
insert into t3 values (0);
insert into i3 values (0);
Select * from t3 union select * from u3 intersect select * from i3;
x
0
SELECT * FROM t3 UNION SELECT * FROM u3 INTERSECT ALL SELECT * FROM i3;
x
0
drop tables t3, u3, i3;
# First line of these results is column names, not the result
# (pay attention to "affected rows")
values (1, 2) union all values (1, 2);
1 2
1 2
1 2
affected rows: 2
values (1, 2) union all values (1, 2) union values (4, 3) union all values (4, 3);
1 2
1 2
4 3
4 3
affected rows: 3
values (1, 2) union all values (1, 2) union values (4, 3) union all values (4, 3) union all values (1, 2);
1 2
1 2
4 3
4 3
1 2
affected rows: 4
values (1, 2) union all values (1, 2) union values (4, 3) union all values (4, 3) union all values (1, 2) union values (1, 2);
1 2
1 2
4 3
affected rows: 2
create table t1 (a int, b int);
create table t2 like t1;
insert t1 values (1, 2), (1, 2), (1, 2), (2, 3), (2, 3), (3, 4), (3, 4);
insert t2 values (1, 2), (1, 2), (2, 3), (2, 3), (2, 3), (2, 3), (4, 5);
select * from t1 intersect select * from t2;
a b
1 2
2 3
select * from t1 intersect all select * from t2;
a b
1 2
2 3
1 2
2 3
# Default: first INTERSECT ALL, then UNION
# Oracle: first UNION, then INTERSECT ALL
select * from t1 union values (1, 2) intersect all select * from t2;
a b
1 2
2 3
select * from t1 union (values (1, 2) intersect all select * from t2);
a b
1 2
2 3
3 4
(select * from t1 union values (1, 2)) intersect all select * from t2;
a b
1 2
2 3
select * from t1 intersect all select * from t2 union values (1, 2);
a b
1 2
2 3
1 2
2 3
select * from t1 intersect all (select * from t2 union values (1, 2));
a b
1 2
2 3
(select * from t1 intersect all select * from t2) union values (1, 2);
a b
1 2
2 3
explain select * from t1 intersect all select * from t2 union values (1, 2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 7
2 INTERSECT t2 ALL NULL NULL NULL NULL 7
3 UNION NULL NULL NULL NULL NULL NULL NULL No tables used
NULL UNIT RESULT <unit1,2,3> ALL NULL NULL NULL NULL NULL
drop tables t1, t2;
set sql_mode= default;

View File

@ -325,4 +325,70 @@ select * from t2 where a < 5
intersect all
select * from t3 where a < 5;
drop table t1,t2,t3;
drop table t1,t2,t3;
--echo #
--echo # MDEV-25158 Segfault on INTERSECT ALL with UNION in Oracle mode
--echo #
create table t3 (x int);
create table u3 (x int);
create table i3 (x int);
explain SELECT * from t3 union select * from u3 intersect all select * from i3;
set sql_mode= 'oracle';
explain SELECT * from t3 union select * from u3 intersect all select * from i3;
select * from t3 union select * from u3 intersect select * from i3;
SELECT * from t3 union select * from u3 intersect all select * from i3;
insert into t3 values (0);
insert into i3 values (0);
Select * from t3 union select * from u3 intersect select * from i3;
SELECT * FROM t3 UNION SELECT * FROM u3 INTERSECT ALL SELECT * FROM i3;
drop tables t3, u3, i3;
--enable_info
--echo # First line of these results is column names, not the result
--echo # (pay attention to "affected rows")
# MSSQL:
# 1 2
# 1 2
values (1, 2) union all values (1, 2);
# MSSQL:
# 1 2
# 4 3
# 4 3
values (1, 2) union all values (1, 2) union values (4, 3) union all values (4, 3);
# MSSQL:
# 1 2
# 4 3
# 4 3
# 1 2
values (1, 2) union all values (1, 2) union values (4, 3) union all values (4, 3) union all values (1, 2);
# MSSQL:
# 1 2
# 4 3
values (1, 2) union all values (1, 2) union values (4, 3) union all values (4, 3) union all values (1, 2) union values (1, 2);
--disable_info
create table t1 (a int, b int);
create table t2 like t1;
insert t1 values (1, 2), (1, 2), (1, 2), (2, 3), (2, 3), (3, 4), (3, 4);
insert t2 values (1, 2), (1, 2), (2, 3), (2, 3), (2, 3), (2, 3), (4, 5);
select * from t1 intersect select * from t2;
select * from t1 intersect all select * from t2;
--echo # Default: first INTERSECT ALL, then UNION
--echo # Oracle: first UNION, then INTERSECT ALL
# VIEW is stored and executed normal mode (see Sql_mode_save_for_frm_handling)
--disable_view_protocol
select * from t1 union values (1, 2) intersect all select * from t2;
--enable_view_protocol
select * from t1 union (values (1, 2) intersect all select * from t2);
(select * from t1 union values (1, 2)) intersect all select * from t2;
select * from t1 intersect all select * from t2 union values (1, 2);
select * from t1 intersect all (select * from t2 union values (1, 2));
(select * from t1 intersect all select * from t2) union values (1, 2);
explain select * from t1 intersect all select * from t2 union values (1, 2);
drop tables t1, t2;
set sql_mode= default;

View File

@ -474,21 +474,30 @@ int select_unit::update_counter(Field* counter, longlong value)
Try to disable index
@retval
true index is disabled this time
true index is disabled and unfold is needed
false this time did not disable the index
*/
bool select_unit_ext::disable_index_if_needed(SELECT_LEX *curr_sl)
{
const bool oracle_mode= thd->variables.sql_mode & MODE_ORACLE;
if (is_index_enabled &&
(curr_sl == curr_sl->master_unit()->union_distinct ||
((!oracle_mode &&
curr_sl == curr_sl->master_unit()->union_distinct) ||
!curr_sl->next_select()) )
{
is_index_enabled= false;
if (table->file->ha_disable_indexes(key_map(0), false))
int error= table->file->ha_disable_indexes(key_map(0), false);
if (error)
{
table->file->print_error(error, MYF(0));
DBUG_ASSERT(0);
return false;
}
table->no_keyread=1;
return true;
/* In case of Oracle mode we unfold at the last operator */
DBUG_ASSERT(!oracle_mode || !curr_sl->next_select());
return oracle_mode || !curr_sl->distinct;
}
return false;
}
@ -772,8 +781,7 @@ bool select_unit_ext::send_eof()
next_sl &&
next_sl->get_linkage() == INTERSECT_TYPE &&
!next_sl->distinct;
bool need_unfold= (disable_index_if_needed(curr_sl) &&
!curr_sl->distinct);
bool need_unfold= disable_index_if_needed(curr_sl);
if (((curr_sl->distinct && !is_next_distinct) ||
curr_op_type == INTERSECT_ALL ||
@ -781,7 +789,8 @@ bool select_unit_ext::send_eof()
!need_unfold)
{
if (!next_sl)
DBUG_ASSERT(curr_op_type != INTERSECT_ALL);
DBUG_ASSERT((thd->variables.sql_mode & MODE_ORACLE) ||
curr_op_type != INTERSECT_ALL);
bool need_update_row;
if (unlikely(table->file->ha_rnd_init_with_error(1)))
return 1;
@ -1295,8 +1304,8 @@ bool st_select_lex_unit::prepare(TABLE_LIST *derived_arg,
uint union_part_count= 0;
select_result *tmp_result;
bool is_union_select;
bool have_except= false, have_intersect= false,
have_except_all_or_intersect_all= false;
bool have_except= false, have_intersect= false;
have_except_all_or_intersect_all= false;
bool instantiate_tmp_table= false;
bool single_tvc= !first_sl->next_select() && first_sl->tvc;
bool single_tvc_wo_order= single_tvc && !first_sl->order_list.elements;
@ -2160,6 +2169,7 @@ bool st_select_lex_unit::exec()
bool first_execution= !executed;
DBUG_ENTER("st_select_lex_unit::exec");
bool was_executed= executed;
int error;
if (executed && !uncacheable && !describe)
DBUG_RETURN(FALSE);
@ -2243,17 +2253,32 @@ bool st_select_lex_unit::exec()
if (likely(!saved_error))
{
records_at_start= table->file->stats.records;
/* select_unit::send_data() writes rows to (temporary) table */
if (sl->tvc)
sl->tvc->exec(sl);
else
sl->join->exec();
/*
Allow UNION ALL to work: disable unique key. We cannot disable indexes
in the middle of the query because enabling indexes requires table to be empty
(see heap_enable_indexes()). So there is special union_distinct property
which is the rightmost distinct UNION in the expression and we release
the unique key after the last (rightmost) distinct UNION, therefore only the
subsequent UNION ALL work as non-distinct.
*/
if (sl == union_distinct && !have_except_all_or_intersect_all &&
!(with_element && with_element->is_recursive))
{
// This is UNION DISTINCT, so there should be a fake_select_lex
DBUG_ASSERT(fake_select_lex != NULL);
if (table->file->ha_disable_indexes(key_map(0), false))
error= table->file->ha_disable_indexes(key_map(0), false);
if (error)
{
table->file->print_error(error, MYF(0));
DBUG_ASSERT(0);
DBUG_RETURN(TRUE);
}
table->no_keyread=1;
}
if (!sl->tvc)