Commit 035ddb82 authored by unknown's avatar unknown

Bug #21019: First result of SELECT COUNT(*) different than consecutive runs

 When optimizing conditions like 'a = <some_val> OR a IS NULL' so that they're
 united into a single condition on the key and checked together the server must 
 check which value is the NULL value in a correct way : not only using ->is_null 
 but also check if the expression doesn't depend on any tables referenced in the 
 current statement. 
 This additional check must be performed because that optimization takes place 
 before the actual execution of the statement, so if the field was initialized 
 to NULL from a previous statement the optimization would be applied incorrectly.


mysql-test/r/select.result:
  Bug #21019: First result of SELECT COUNT(*) different than consecutive runs
   - test case
mysql-test/t/select.test:
  Bug #21019: First result of SELECT COUNT(*) different than consecutive runs
   - test case. 
     Note that ALTER TABLE is important here : it happens to
     leave the Field instance for t1.b set to NULL, witch is vital for
     demonstrating the problem fixed by this changeset.
sql/sql_select.cc:
  Bug #21019: First result of SELECT COUNT(*) different than consecutive runs
   - check whether a value is null taking into account its table dependency.
parent 1b03ac4c
...@@ -2744,3 +2744,29 @@ SELECT i='1e+01',i=1e+01, i in (1e+01), i in ('1e+01') FROM t1; ...@@ -2744,3 +2744,29 @@ SELECT i='1e+01',i=1e+01, i in (1e+01), i in ('1e+01') FROM t1;
i='1e+01' i=1e+01 i in (1e+01) i in ('1e+01') i='1e+01' i=1e+01 i in (1e+01) i in ('1e+01')
0 1 1 1 0 1 1 1
DROP TABLE t1; DROP TABLE t1;
CREATE TABLE t1 (a int, b int);
INSERT INTO t1 VALUES (1,1), (2,1), (4,10);
CREATE TABLE t2 (a int PRIMARY KEY, b int, KEY b (b));
INSERT INTO t2 VALUES (1,NULL), (2,10);
ALTER TABLE t1 ENABLE KEYS;
EXPLAIN SELECT STRAIGHT_JOIN SQL_NO_CACHE COUNT(*) FROM t2, t1 WHERE t1.b = t2.b OR t2.b IS NULL;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 index b b 5 NULL 2 Using index
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where
SELECT STRAIGHT_JOIN SQL_NO_CACHE * FROM t2, t1 WHERE t1.b = t2.b OR t2.b IS NULL;
a b a b
1 NULL 1 1
1 NULL 2 1
1 NULL 4 10
2 10 4 10
EXPLAIN SELECT STRAIGHT_JOIN SQL_NO_CACHE COUNT(*) FROM t2, t1 WHERE t1.b = t2.b OR t2.b IS NULL;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t2 index b b 5 NULL 2 Using index
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where
SELECT STRAIGHT_JOIN SQL_NO_CACHE * FROM t2, t1 WHERE t1.b = t2.b OR t2.b IS NULL;
a b a b
1 NULL 1 1
1 NULL 2 1
1 NULL 4 10
2 10 4 10
DROP TABLE IF EXISTS t1,t2;
...@@ -2297,4 +2297,19 @@ INSERT INTO t1 VALUES (10); ...@@ -2297,4 +2297,19 @@ INSERT INTO t1 VALUES (10);
SELECT i='1e+01',i=1e+01, i in (1e+01), i in ('1e+01') FROM t1; SELECT i='1e+01',i=1e+01, i in (1e+01), i in ('1e+01') FROM t1;
DROP TABLE t1; DROP TABLE t1;
#
# Bug #21019: First result of SELECT COUNT(*) different than consecutive runs
#
CREATE TABLE t1 (a int, b int);
INSERT INTO t1 VALUES (1,1), (2,1), (4,10);
CREATE TABLE t2 (a int PRIMARY KEY, b int, KEY b (b));
INSERT INTO t2 VALUES (1,NULL), (2,10);
ALTER TABLE t1 ENABLE KEYS;
EXPLAIN SELECT STRAIGHT_JOIN SQL_NO_CACHE COUNT(*) FROM t2, t1 WHERE t1.b = t2.b OR t2.b IS NULL;
SELECT STRAIGHT_JOIN SQL_NO_CACHE * FROM t2, t1 WHERE t1.b = t2.b OR t2.b IS NULL;
EXPLAIN SELECT STRAIGHT_JOIN SQL_NO_CACHE COUNT(*) FROM t2, t1 WHERE t1.b = t2.b OR t2.b IS NULL;
SELECT STRAIGHT_JOIN SQL_NO_CACHE * FROM t2, t1 WHERE t1.b = t2.b OR t2.b IS NULL;
DROP TABLE IF EXISTS t1,t2;
# End of 4.1 tests # End of 4.1 tests
...@@ -2143,8 +2143,11 @@ merge_key_fields(KEY_FIELD *start,KEY_FIELD *new_fields,KEY_FIELD *end, ...@@ -2143,8 +2143,11 @@ merge_key_fields(KEY_FIELD *start,KEY_FIELD *new_fields,KEY_FIELD *end,
/* field = expression OR field IS NULL */ /* field = expression OR field IS NULL */
old->level= and_level; old->level= and_level;
old->optimize= KEY_OPTIMIZE_REF_OR_NULL; old->optimize= KEY_OPTIMIZE_REF_OR_NULL;
/* Remember the NOT NULL value */ /*
if (old->val->is_null()) Remember the NOT NULL value unless the value does not depend
on other tables.
*/
if (!old->val->used_tables() && old->val->is_null())
old->val= new_fields->val; old->val= new_fields->val;
/* The referred expression can be NULL: */ /* The referred expression can be NULL: */
old->null_rejecting= 0; old->null_rejecting= 0;
......
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