Commit a405d30e authored by Sergey Glukhov's avatar Sergey Glukhov

Bug#12540545 61101: ASSERTION FAILURE IN THREAD 1256741184 IN FILE /BUILDDIR/BUILD/BUILD/MYSQ

The assertion in innodb is triggered in this way:
1. mysql server does lookup on the primary key with full key,
   innodb decides to not store cursor position because
   "any index_next/prev call will return EOF anyway"
2. server asks innodb to return any next record in the index and the
   assertion is triggered because no cursor position is stored.

It happens when a unique search (match_mode=ROW_SEL_EXACT)
in the clustered index is performed. InnoDB has never stored
the cursor position after a unique key lookup in the
clustered index because storing the position is an expensive
operation. The bug was introduced by 
WL3220 'Loose index scan for aggregate functions'.

The fix is to disallow loose index scan optimization
for AGG_FUNC(DISTINCT ...) if GROUP_MIN_MAX quick select
uses clustered key.


mysql-test/r/group_min_max_innodb.result:
  test case
mysql-test/t/group_min_max_innodb.test:
  test case
sql/opt_range.cc:
  disallow loose index scan optimization for 
  AGG_FUNC(DISTINCT ...) if GROUP_MIN_MAX
  quick select uses clustered key.
parent 42d39e6e
...@@ -94,3 +94,27 @@ pk ...@@ -94,3 +94,27 @@ pk
drop view v1; drop view v1;
drop table t1; drop table t1;
End of 5.1 tests End of 5.1 tests
#
# Bug#12540545 61101: ASSERTION FAILURE IN THREAD 1256741184 IN
# FILE /BUILDDIR/BUILD/BUILD/MYSQ
#
CREATE TABLE t1 (a CHAR(1), b CHAR(1), PRIMARY KEY (a,b)) ENGINE=InnoDB;
INSERT INTO t1 VALUES ('a', 'b'), ('c', 'd');
EXPLAIN SELECT COUNT(DISTINCT a) FROM t1 WHERE b = 'b';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL PRIMARY 2 NULL 2 Using where; Using index
SELECT COUNT(DISTINCT a) FROM t1 WHERE b = 'b';
COUNT(DISTINCT a)
1
DROP TABLE t1;
CREATE TABLE t1 (a CHAR(1) NOT NULL, b CHAR(1) NOT NULL, UNIQUE KEY (a,b))
ENGINE=InnoDB;
INSERT INTO t1 VALUES ('a', 'b'), ('c', 'd');
EXPLAIN SELECT COUNT(DISTINCT a) FROM t1 WHERE b = 'b';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL a 2 NULL 2 Using where; Using index
SELECT COUNT(DISTINCT a) FROM t1 WHERE b = 'b';
COUNT(DISTINCT a)
1
DROP TABLE t1;
End of 5.5 tests
...@@ -117,3 +117,23 @@ drop view v1; ...@@ -117,3 +117,23 @@ drop view v1;
drop table t1; drop table t1;
--echo End of 5.1 tests --echo End of 5.1 tests
--echo #
--echo # Bug#12540545 61101: ASSERTION FAILURE IN THREAD 1256741184 IN
--echo # FILE /BUILDDIR/BUILD/BUILD/MYSQ
--echo #
CREATE TABLE t1 (a CHAR(1), b CHAR(1), PRIMARY KEY (a,b)) ENGINE=InnoDB;
INSERT INTO t1 VALUES ('a', 'b'), ('c', 'd');
EXPLAIN SELECT COUNT(DISTINCT a) FROM t1 WHERE b = 'b';
SELECT COUNT(DISTINCT a) FROM t1 WHERE b = 'b';
DROP TABLE t1;
CREATE TABLE t1 (a CHAR(1) NOT NULL, b CHAR(1) NOT NULL, UNIQUE KEY (a,b))
ENGINE=InnoDB;
INSERT INTO t1 VALUES ('a', 'b'), ('c', 'd');
EXPLAIN SELECT COUNT(DISTINCT a) FROM t1 WHERE b = 'b';
SELECT COUNT(DISTINCT a) FROM t1 WHERE b = 'b';
DROP TABLE t1;
--echo End of 5.5 tests
...@@ -9318,6 +9318,11 @@ cost_group_min_max(TABLE* table, KEY *index_info, uint used_key_parts, ...@@ -9318,6 +9318,11 @@ cost_group_min_max(TABLE* table, KEY *index_info, uint used_key_parts,
except MIN and MAX. For queries with DISTINCT, aggregate functions except MIN and MAX. For queries with DISTINCT, aggregate functions
are allowed. are allowed.
SA5. The select list in DISTINCT queries should not contain expressions. SA5. The select list in DISTINCT queries should not contain expressions.
SA6. Clustered index can not be used by GROUP_MIN_MAX quick select
for AGG_FUNC(DISTINCT ...) optimization because cursor position is
never stored after a unique key lookup in the clustered index and
furhter index_next/prev calls can not be used. So loose index scan
optimization can not be used in this case.
GA1. If Q has a GROUP BY clause, then GA is a prefix of I. That is, if GA1. If Q has a GROUP BY clause, then GA is a prefix of I. That is, if
G_i = A_j => i = j. G_i = A_j => i = j.
GA2. If Q has a DISTINCT clause, then there is a permutation of SA that GA2. If Q has a DISTINCT clause, then there is a permutation of SA that
...@@ -9804,6 +9809,13 @@ get_best_group_min_max(PARAM *param, SEL_TREE *tree, double read_time) ...@@ -9804,6 +9809,13 @@ get_best_group_min_max(PARAM *param, SEL_TREE *tree, double read_time)
Field::itMBR : Field::itRAW)) Field::itMBR : Field::itRAW))
DBUG_RETURN(NULL); DBUG_RETURN(NULL);
/*
Check (SA6) if clustered key is used
*/
if (is_agg_distinct && index == table->s->primary_key &&
table->file->primary_key_is_clustered())
DBUG_RETURN(NULL);
/* The query passes all tests, so construct a new TRP object. */ /* The query passes all tests, so construct a new TRP object. */
read_plan= new (param->mem_root) read_plan= new (param->mem_root)
TRP_GROUP_MIN_MAX(have_min, have_max, is_agg_distinct, TRP_GROUP_MIN_MAX(have_min, have_max, is_agg_distinct,
......
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