Commit 16258677 authored by Monty's avatar Monty

MDEV-6768 Wrong result with aggregate with join with no result set

When a query does implicit grouping and join operation produces an empty
result set, a NULL-complemented row combination is generated.
However, constant table fields still show non-NULL values.

What happens in the is that end_send_group() is called with a
const row but without any rows matching the WHERE clause.
This last part is shown by 'join->first_record' not being set.

This causes item->no_rows_in_result() to be called for all items to reset
all sum functions to their initial state. However fields are not set
to NULL.

The used fix is to produce NULL-complemented records for constant tables
as well. Also, reset the constant table's records back in case we're
in a subquery which may get re-executed.
An alternative fix would have item->no_rows_in_result() also work
with Item_field objects.

There is some other issues with the code:
- join->no_rows_in_result_called is used but never set.
- Tables that are used with group functions are not properly marked as
  maybe_null, which is required if the table rows should be regarded as
  null-complemented (not existing).
- The code that tries to detect if mixed_implicit_grouping should be set
  didn't take into account all usage of fields and sum functions.
- Item_func::restore_to_before_no_rows_in_result() called the wrong
  function.
- join->clear() does not use a table_map argument to clear_tables(),
  which caused it to ignore constant tables.
- unclear_tables() does not correctly restore status to what is
  was before clear_tables().

Main bug fix was to always use a table_map argument to clear_tables() and
always use join->clear() and clear_tables() together with unclear_tables().

Other fixes:
- Fixed Item_func::restore_to_before_no_rows_in_result()
- Set 'join->no_rows_in_result_called' when no_rows_in_result_set()
  is called.
- Removed not used argument from setup_end_select_func().
- More code comments
- Ensure that end_send_group() modifies the same fields as are in the
  result set.
- Changed return_zero_rows() to use pointers instead of references,
  similar to the rest of the code.

Reviewer: Sergei Petrunia <sergey@mariadb.com>
parent c0adb05b
...@@ -4095,5 +4095,115 @@ MIN(pk) a ...@@ -4095,5 +4095,115 @@ MIN(pk) a
5 10 5 10
DROP TABLE t1; DROP TABLE t1;
# #
# MDEV-6768 Wrong result with agregate with join with no resultset
#
create table t1
(
PARENT_ID int(10) unsigned NOT NULL AUTO_INCREMENT,
PARENT_FIELD VARCHAR(10),
PRIMARY KEY (PARENT_ID)
) engine=innodb;
create table t2
(
CHILD_ID INT NOT NULL AUTO_INCREMENT,
PARENT_ID INT NOT NULL,
CHILD_FIELD varchar(10),
PRIMARY KEY (CHILD_ID)
)engine=innodb;
INSERT INTO t1 (PARENT_FIELD)
SELECT 'AAAA';
INSERT INTO t2 (PARENT_ID, CHILD_FIELD)
SELECT 1, 'BBBB';
explain select
t1.PARENT_ID,
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1 Using index
1 SIMPLE t2 ALL NULL NULL NULL NULL 1 Using where
select
t1.PARENT_ID,
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
PARENT_ID min(CHILD_FIELD)
NULL NULL
select
1,
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
1 min(CHILD_FIELD)
1 NULL
select
IFNULL(t1.PARENT_ID,1),
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
IFNULL(t1.PARENT_ID,1) min(CHILD_FIELD)
1 NULL
# Check that things works with MyISAM (which has different explain)
alter table t1 engine=myisam;
alter table t2 engine=myisam;
explain select
t1.PARENT_ID,
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
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
t1.PARENT_ID,
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
PARENT_ID min(CHILD_FIELD)
NULL NULL
drop table t1,t2;
# Check that things works if sub queries are re-executed
create table t1 (a int primary key, b int);
create table t2 (a int primary key, b int);
create table t3 (a int primary key, b int);
insert into t1 values (1,1),(2,2),(3,3);
insert into t2 values (1,1),(2,2),(3,3);
insert into t3 values (1,1),(3,3);
explain
select *,
(select
CONCAT('t2:', IFNULL(t2.a, 't2a-null'), ';',
'min_t3_b:', IFNULL(min(t3.b), 't3b-null'))
from t2,t3
where t2.a=1 and t1.b = t3.a) as s1
from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 3
2 DEPENDENT SUBQUERY t2 const PRIMARY PRIMARY 4 const 1 Using index
2 DEPENDENT SUBQUERY t3 eq_ref PRIMARY PRIMARY 4 test.t1.b 1
select *,
(select
CONCAT('t2:', IFNULL(t2.a, 't2a-null'), ';',
'min_t3_b:', IFNULL(min(t3.b), 't3b-null'))
from t2,t3
where t2.a=1 and t1.b = t3.a) as s1
from t1;
a b s1
1 1 t2:1;min_t3_b:1
2 2 t2:t2a-null;min_t3_b:t3b-null
3 3 t2:1;min_t3_b:3
drop table t1,t2,t3;
#
# End of 10.5 tests # End of 10.5 tests
# #
...@@ -1748,6 +1748,116 @@ SELECT MIN(pk), a FROM t1 WHERE pk <> 1 GROUP BY a; ...@@ -1748,6 +1748,116 @@ SELECT MIN(pk), a FROM t1 WHERE pk <> 1 GROUP BY a;
DROP TABLE t1; DROP TABLE t1;
--echo #
--echo # MDEV-6768 Wrong result with agregate with join with no resultset
--echo #
create table t1
(
PARENT_ID int(10) unsigned NOT NULL AUTO_INCREMENT,
PARENT_FIELD VARCHAR(10),
PRIMARY KEY (PARENT_ID)
) engine=innodb;
create table t2
(
CHILD_ID INT NOT NULL AUTO_INCREMENT,
PARENT_ID INT NOT NULL,
CHILD_FIELD varchar(10),
PRIMARY KEY (CHILD_ID)
)engine=innodb;
INSERT INTO t1 (PARENT_FIELD)
SELECT 'AAAA';
INSERT INTO t2 (PARENT_ID, CHILD_FIELD)
SELECT 1, 'BBBB';
explain select
t1.PARENT_ID,
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
select
t1.PARENT_ID,
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
select
1,
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
select
IFNULL(t1.PARENT_ID,1),
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
--echo # Check that things works with MyISAM (which has different explain)
alter table t1 engine=myisam;
alter table t2 engine=myisam;
explain select
t1.PARENT_ID,
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
select
t1.PARENT_ID,
min(CHILD_FIELD)
from t1 straight_join t2
where t1.PARENT_ID = 1
and t1.PARENT_ID = t2.PARENT_ID
and t2.CHILD_FIELD = "ZZZZ";
drop table t1,t2;
--echo # Check that things works if sub queries are re-executed
create table t1 (a int primary key, b int);
create table t2 (a int primary key, b int);
create table t3 (a int primary key, b int);
insert into t1 values (1,1),(2,2),(3,3);
insert into t2 values (1,1),(2,2),(3,3);
insert into t3 values (1,1),(3,3);
explain
select *,
(select
CONCAT('t2:', IFNULL(t2.a, 't2a-null'), ';',
'min_t3_b:', IFNULL(min(t3.b), 't3b-null'))
from t2,t3
where t2.a=1 and t1.b = t3.a) as s1
from t1;
select *,
(select
CONCAT('t2:', IFNULL(t2.a, 't2a-null'), ';',
'min_t3_b:', IFNULL(min(t3.b), 't3b-null'))
from t2,t3
where t2.a=1 and t1.b = t3.a) as s1
from t1;
drop table t1,t2,t3;
--echo # --echo #
--echo # End of 10.5 tests --echo # End of 10.5 tests
--echo # --echo #
...@@ -1230,6 +1230,8 @@ SELECT * FROM t1 HAVING MIN(t1.c1) >= ALL(SELECT 'a' UNION SELECT 'r'); ...@@ -1230,6 +1230,8 @@ SELECT * FROM t1 HAVING MIN(t1.c1) >= ALL(SELECT 'a' UNION SELECT 'r');
c1 c1
Warnings: Warnings:
Warning 1292 Truncated incorrect datetime value: 'r' Warning 1292 Truncated incorrect datetime value: 'r'
SELECT * FROM t1 HAVING MIN(t1.c1) > 0;
c1
DROP TABLE t1; DROP TABLE t1;
CREATE TABLE t1 (c1 timestamp); CREATE TABLE t1 (c1 timestamp);
INSERT INTO t1 VALUES ('2010-01-01 00:00:00'); INSERT INTO t1 VALUES ('2010-01-01 00:00:00');
......
...@@ -810,6 +810,7 @@ DROP TABLE t1; ...@@ -810,6 +810,7 @@ DROP TABLE t1;
CREATE TABLE t1 (c1 timestamp); CREATE TABLE t1 (c1 timestamp);
SELECT MIN(t1.c1) AS k1 FROM t1 HAVING (k1 >= ALL(SELECT 'a' UNION SELECT 'r')); SELECT MIN(t1.c1) AS k1 FROM t1 HAVING (k1 >= ALL(SELECT 'a' UNION SELECT 'r'));
SELECT * FROM t1 HAVING MIN(t1.c1) >= ALL(SELECT 'a' UNION SELECT 'r'); SELECT * FROM t1 HAVING MIN(t1.c1) >= ALL(SELECT 'a' UNION SELECT 'r');
SELECT * FROM t1 HAVING MIN(t1.c1) > 0;
DROP TABLE t1; DROP TABLE t1;
CREATE TABLE t1 (c1 timestamp); CREATE TABLE t1 (c1 timestamp);
......
...@@ -380,7 +380,7 @@ class Item_func :public Item_func_or_sum, ...@@ -380,7 +380,7 @@ class Item_func :public Item_func_or_sum,
{ {
for (uint i= 0; i < arg_count; i++) for (uint i= 0; i < arg_count; i++)
{ {
args[i]->no_rows_in_result(); args[i]->restore_to_before_no_rows_in_result();
} }
} }
void convert_const_compared_to_int_field(THD *thd); void convert_const_compared_to_int_field(THD *thd);
......
This diff is collapsed.
...@@ -227,7 +227,7 @@ enum sj_strategy_enum ...@@ -227,7 +227,7 @@ enum sj_strategy_enum
typedef enum_nested_loop_state typedef enum_nested_loop_state
(*Next_select_func)(JOIN *, struct st_join_table *, bool); (*Next_select_func)(JOIN *, struct st_join_table *, bool);
Next_select_func setup_end_select_func(JOIN *join, JOIN_TAB *tab); Next_select_func setup_end_select_func(JOIN *join);
int rr_sequential(READ_RECORD *info); int rr_sequential(READ_RECORD *info);
int rr_sequential_and_unpack(READ_RECORD *info); int rr_sequential_and_unpack(READ_RECORD *info);
Item *remove_pushed_top_conjuncts(THD *thd, Item *cond); Item *remove_pushed_top_conjuncts(THD *thd, Item *cond);
...@@ -1767,7 +1767,8 @@ class JOIN :public Sql_alloc ...@@ -1767,7 +1767,8 @@ class JOIN :public Sql_alloc
void join_free(); void join_free();
/** Cleanup this JOIN, possibly for reuse */ /** Cleanup this JOIN, possibly for reuse */
void cleanup(bool full); void cleanup(bool full);
void clear(); void clear(table_map *cleared_tables);
void inline clear_sum_funcs();
bool send_row_on_empty_set() bool send_row_on_empty_set()
{ {
return (do_send_rows && implicit_grouping && !group_optimized_away && return (do_send_rows && implicit_grouping && !group_optimized_away &&
......
...@@ -3306,10 +3306,16 @@ inline void mark_as_null_row(TABLE *table) ...@@ -3306,10 +3306,16 @@ inline void mark_as_null_row(TABLE *table)
bfill(table->null_flags,table->s->null_bytes,255); bfill(table->null_flags,table->s->null_bytes,255);
} }
/*
Restore table to state before mark_as_null_row() call.
This assumes that the caller has restored table->null_flags,
as is done in unclear_tables().
*/
inline void unmark_as_null_row(TABLE *table) inline void unmark_as_null_row(TABLE *table)
{ {
table->null_row=0; table->null_row= 0;
table->status= STATUS_NO_RECORD; table->status&= ~STATUS_NULL_ROW;
} }
bool is_simple_order(ORDER *order); bool is_simple_order(ORDER *order);
......
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