Commit 891609b5 authored by Varun Gupta's avatar Varun Gupta

MDEV-21318: Wrong results with window functions and implicit grouping

The issue here is for degenerate joins we should execute the window
function but it is not getting executed in all the cases.

To get the window function values window function needs to be executed
always. This currently does not happen in few cases
where the join would return 0 or 1 row like
  1) IMPOSSIBLE WHERE
  2) MIN/MAX optimization
  3) EMPTY CONST TABLE

The fix is to make sure that window functions get executed
and the temporary table is setup for the execution of window functions
parent 3dfe1ba3
......@@ -3653,5 +3653,76 @@ COUNT(*) OVER () MOD(MIN(i),2)
3 1
drop table t1;
#
# MDEV-21318: Wrong results with window functions and implicit grouping
#
CREATE TABLE t1 (a INT);
#
# With empty const table
# The expected result here is 1, NULL
#
explain
SELECT row_number() over(), sum(1) FROM t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 system NULL NULL NULL NULL 0 const row not found; Using temporary
SELECT row_number() over(), sum(1) FROM t1;
row_number() over() sum(1)
1 NULL
insert into t1 values (2);
#
# Const table has 1 row, but still impossible where
# The expected result here is 1, NULL
#
EXPLAIN SELECT row_number() over(), sum(1) FROM t1 where a=1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables
SELECT row_number() over(), sum(1) FROM t1 where a=1;
row_number() over() sum(1)
1 NULL
#
# Impossible HAVING
# Empty result is expected
#
EXPLAIN SELECT row_number() over(), sum(1) FROM t1 where a=1 having 1=0;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible HAVING
SELECT row_number() over(), sum(1) FROM t1 where a=1 having 1=0;
row_number() over() sum(1)
#
# const table has 1 row, no impossible where
# The expected result here is 1, 2
#
EXPLAIN SELECT row_number() over(), sum(a) FROM t1 where a=2;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 system NULL NULL NULL NULL 1 Using temporary
SELECT row_number() over(), sum(a) FROM t1 where a=2;
row_number() over() sum(a)
1 2
drop table t1;
#
# Impossible Where
#
create table t1(a int);
insert into t1 values (1);
#
# Expected result is NULL, 0, NULL
#
EXPLAIN SELECT MAX(a) OVER (), COUNT(a), abs(a) FROM t1 WHERE FALSE;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE
SELECT MAX(a) OVER (), COUNT(a), abs(a) FROM t1 WHERE FALSE;
MAX(a) OVER () COUNT(a) abs(a)
NULL 0 NULL
#
# Expected result is 1, 0, NULL
#
EXPLAIN
SELECT MAX(1) OVER (), COUNT(a), abs(a) FROM t1 WHERE FALSE;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE
SELECT MAX(1) OVER (), COUNT(a), abs(a) FROM t1 WHERE FALSE;
MAX(1) OVER () COUNT(a) abs(a)
1 0 NULL
drop table t1;
#
# End of 10.2 tests
#
......@@ -2361,6 +2361,71 @@ INSERT INTO t1 VALUES (1),(0),(1),(2),(0),(1),(2),(1),(2);
SELECT DISTINCT COUNT(*) OVER (), MOD(MIN(i),2) FROM t1 GROUP BY i ;
drop table t1;
--echo #
--echo # MDEV-21318: Wrong results with window functions and implicit grouping
--echo #
CREATE TABLE t1 (a INT);
--echo #
--echo # With empty const table
--echo # The expected result here is 1, NULL
--echo #
explain
SELECT row_number() over(), sum(1) FROM t1;
SELECT row_number() over(), sum(1) FROM t1;
insert into t1 values (2);
--echo #
--echo # Const table has 1 row, but still impossible where
--echo # The expected result here is 1, NULL
--echo #
EXPLAIN SELECT row_number() over(), sum(1) FROM t1 where a=1;
SELECT row_number() over(), sum(1) FROM t1 where a=1;
--echo #
--echo # Impossible HAVING
--echo # Empty result is expected
--echo #
EXPLAIN SELECT row_number() over(), sum(1) FROM t1 where a=1 having 1=0;
SELECT row_number() over(), sum(1) FROM t1 where a=1 having 1=0;
--echo #
--echo # const table has 1 row, no impossible where
--echo # The expected result here is 1, 2
--echo #
EXPLAIN SELECT row_number() over(), sum(a) FROM t1 where a=2;
SELECT row_number() over(), sum(a) FROM t1 where a=2;
drop table t1;
--echo #
--echo # Impossible Where
--echo #
create table t1(a int);
insert into t1 values (1);
--echo #
--echo # Expected result is NULL, 0, NULL
--echo #
EXPLAIN SELECT MAX(a) OVER (), COUNT(a), abs(a) FROM t1 WHERE FALSE;
SELECT MAX(a) OVER (), COUNT(a), abs(a) FROM t1 WHERE FALSE;
--echo #
--echo # Expected result is 1, 0, NULL
--echo #
EXPLAIN
SELECT MAX(1) OVER (), COUNT(a), abs(a) FROM t1 WHERE FALSE;
SELECT MAX(1) OVER (), COUNT(a), abs(a) FROM t1 WHERE FALSE;
drop table t1;
--echo #
--echo # End of 10.2 tests
--echo #
......@@ -1447,6 +1447,7 @@ JOIN::optimize_inner()
zero_result_cause= "Zero limit";
}
table_count= top_join_tab_count= 0;
handle_implicit_grouping_with_window_funcs();
error= 0;
goto setup_subq_exit;
}
......@@ -1502,6 +1503,7 @@ JOIN::optimize_inner()
zero_result_cause= "No matching min/max row";
table_count= top_join_tab_count= 0;
error=0;
handle_implicit_grouping_with_window_funcs();
goto setup_subq_exit;
}
if (res > 1)
......@@ -1517,6 +1519,7 @@ JOIN::optimize_inner()
tables_list= 0; // All tables resolved
select_lex->min_max_opt_list.empty();
const_tables= top_join_tab_count= table_count;
handle_implicit_grouping_with_window_funcs();
/*
Extract all table-independent conditions and replace the WHERE
clause with them. All other conditions were computed by opt_sum_query
......@@ -1615,6 +1618,7 @@ JOIN::optimize_inner()
zero_result_cause= "no matching row in const table";
DBUG_PRINT("error",("Error: %s", zero_result_cause));
error= 0;
handle_implicit_grouping_with_window_funcs();
goto setup_subq_exit;
}
if (!(thd->variables.option_bits & OPTION_BIG_SELECTS) &&
......@@ -1639,6 +1643,7 @@ JOIN::optimize_inner()
zero_result_cause=
"Impossible WHERE noticed after reading const tables";
select_lex->mark_const_derived(zero_result_cause);
handle_implicit_grouping_with_window_funcs();
goto setup_subq_exit;
}
......@@ -1781,6 +1786,7 @@ JOIN::optimize_inner()
zero_result_cause=
"Impossible WHERE noticed after reading const tables";
select_lex->mark_const_derived(zero_result_cause);
handle_implicit_grouping_with_window_funcs();
goto setup_subq_exit;
}
......@@ -18225,7 +18231,8 @@ void set_postjoin_aggr_write_func(JOIN_TAB *tab)
}
}
else if (join->sort_and_group && !tmp_tbl->precomputed_group_by &&
!join->sort_and_group_aggr_tab && join->tables_list)
!join->sort_and_group_aggr_tab && join->tables_list &&
join->top_join_tab_count)
{
DBUG_PRINT("info",("Using end_write_group"));
aggr->set_write_func(end_write_group);
......@@ -26925,6 +26932,28 @@ Item *remove_pushed_top_conjuncts(THD *thd, Item *cond)
return cond;
}
/*
There are 5 cases in which we shortcut the join optimization process as we
conclude that the join would be a degenerate one
1) IMPOSSIBLE WHERE
2) MIN/MAX optimization (@see opt_sum_query)
3) EMPTY CONST TABLE
If a window function is present in any of the above cases then to get the
result of the window function, we need to execute it. So we need to
create a temporary table for its execution. Here we need to take in mind
that aggregate functions and non-aggregate function need not be executed.
*/
void JOIN::handle_implicit_grouping_with_window_funcs()
{
if (select_lex->have_window_funcs() && send_row_on_empty_set())
{
const_tables= top_join_tab_count= table_count= 0;
}
}
/**
@} (end of group Query_Optimizer)
*/
......@@ -1057,6 +1057,7 @@ class JOIN :public Sql_alloc
void restore_query_plan(Join_plan_state *restore_from);
/* Choose a subquery plan for a table-less subquery. */
bool choose_tableless_subquery_plan();
void handle_implicit_grouping_with_window_funcs();
public:
JOIN_TAB *join_tab, **best_ref;
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment