summaryrefslogtreecommitdiff
path: root/mysql-test/t/subselect3.test
diff options
context:
space:
mode:
authorunknown <sergefp@mysql.com>2006-10-31 20:51:09 +0300
committerunknown <sergefp@mysql.com>2006-10-31 20:51:09 +0300
commit48df3b96a1719141749c05e4080c57366e9d0fbe (patch)
tree9720832e2f3ce2403e51f324722b5522b5bac946 /mysql-test/t/subselect3.test
parent3cf49a3dd890bd6229acd8c89b672359e7d16452 (diff)
downloadmariadb-git-48df3b96a1719141749c05e4080c57366e9d0fbe.tar.gz
BUG#8804: wrong results for NULL IN (SELECT ...)
Evaluate "NULL IN (SELECT ...)" in a special way: Disable pushed-down conditions and their "consequences": = Do full table scans instead of unique_[index_subquery] lookups. = Change appropriate "ref_or_null" accesses to full table scans in subquery's joins. Also cache value of NULL IN (SELECT ...) if the SELECT is not correlated wrt any upper select. mysql-test/r/subselect.result: BUG#8804: wrong results for NULL IN (SELECT ...): - Updated test results sql/item.h: BUG#8804: wrong results for NULL IN (SELECT ...): - Added comments sql/item_cmpfunc.cc: BUG#8804: wrong results for NULL IN (SELECT ...): Made Item_in_optimizer to: - cache the value of "NULL IN (uncorrelated select)" - Turn off pushed-down predicates when evaluating "NULL IN (SELECT ...)" sql/item_cmpfunc.h: BUG#8804: wrong results for NULL IN (SELECT ...): - Made Item_in_optimizer cache the value of "NULL IN (uncorrelated select)" - Added comments sql/item_subselect.cc: BUG#8804: wrong results for NULL IN (SELECT ...): - When needed, wrap the predicates we push into subquery into an Item_func_trig_cond so we're able to turn them off when evaluating NULL IN (SELECT ...). - Added code to evaluate NULL IN (SELECT ...) in a special way: = In [unique_]index_subquery, do full table scan to see if there are any rows. = For other subqueries, change ref[_or_null] to ALL if the ref[_or_null] was created from pushed-down predicate. sql/item_subselect.h: BUG#8804: wrong results for NULL IN (SELECT ...): - Added Item_subselect::is_correlated - Added comments sql/records.cc: BUG#8804: wrong results for NULL IN (SELECT ...): - Make rr_sequential() non-static sql/sql_lex.cc: BUG#8804: wrong results for NULL IN (SELECT ...): - Added st_select_lex::is_correlated and Item_subselect::is_correlated. sql/sql_lex.h: BUG#8804: wrong results for NULL IN (SELECT ...): - Added st_select_lex::is_correlated sql/sql_select.cc: BUG#8804: wrong results for NULL IN (SELECT ...): - Added KEY_FIELD::outer_ref to keep track of which ref accesses are created from predicates that were pushed down into the subquery. sql/sql_select.h: BUG#8804: wrong results for NULL IN (SELECT ...): - Added KEYUSE::outer_ref mysql-test/r/subselect3.result: New BitKeeper file ``mysql-test/r/subselect3.result'' mysql-test/t/subselect3.test: New BitKeeper file ``mysql-test/t/subselect3.test''
Diffstat (limited to 'mysql-test/t/subselect3.test')
-rw-r--r--mysql-test/t/subselect3.test137
1 files changed, 137 insertions, 0 deletions
diff --git a/mysql-test/t/subselect3.test b/mysql-test/t/subselect3.test
new file mode 100644
index 00000000000..f7fbafdd17f
--- /dev/null
+++ b/mysql-test/t/subselect3.test
@@ -0,0 +1,137 @@
+--disable_warnings
+drop table if exists t0, t1, t2, t3, t4;
+--enable_warnings
+
+#
+# 1. Subquery with GROUP/HAVING
+#
+create table t1 (oref int, grp int, ie int) ;
+insert into t1 (oref, grp, ie) values
+ (1, 1, 1),
+ (1, 1, 1),
+ (1, 2, NULL),
+
+ (2, 1, 3),
+
+ (3, 1, 4),
+ (3, 2, NULL);
+
+# Ok, for
+# select max(ie) from t1 where oref=PARAM group by grp
+# we'll have:
+# 1 -> (1, NULL) matching + NULL
+# 2 -> (3) non-matching
+# 3 -> (3, NULL) non-matching + NULL
+# 4 -> () nothing.
+
+create table t2 (oref int, a int);
+insert into t2 values
+ (1, 1),
+ (2, 2),
+ (3, 3),
+ (4, NULL),
+ (2, NULL);
+
+# true, false, null, false, null
+select a, oref, a in (select max(ie)
+ from t1 where oref=t2.oref group by grp) from t2;
+
+# This must have a trigcond
+explain extended
+select a, oref, a in (select max(ie)
+ from t1 where oref=t2.oref group by grp) from t2;
+
+# This must not have a trigcond:
+explain extended
+select a, oref from t2
+where a in (select max(ie) from t1 where oref=t2.oref group by grp);
+
+
+# Non-correlated subquery, 2 NULL evaluations
+create table t3 (a int);
+insert into t3 values (NULL), (NULL);
+flush status;
+select a in (select max(ie) from t1 where oref=4 group by grp) from t3;
+show status like 'Handler_read_rnd_next';
+select ' ^ This must show 11' Z;
+
+# This must show trigcond:
+explain extended select a in (select max(ie) from t1 where oref=4 group by grp) from t3;
+
+drop table t1, t2, t3;
+
+#
+# 2. Subquery handled with 'index_subquery':
+#
+create table t1 (a int, oref int, key(a));
+insert into t1 values
+ (1, 1),
+ (1, NULL),
+ (2, 3),
+ (2, NULL),
+ (3, NULL);
+
+create table t2 (a int, oref int);
+insert into t2 values (1, 1), (2,2), (NULL, 3), (NULL, 4);
+
+select oref, a, a in (select a from t1 where oref=t2.oref) Z from t2;
+
+# The next explain shows "using index" but that is just incorrect display
+# (there is a bug filed about this).
+explain extended
+select oref, a, a in (select a from t1 where oref=t2.oref) Z from t2;
+
+flush status;
+select oref, a from t2 where a in (select a from t1 where oref=t2.oref);
+# This will only show access to t2:
+show status like '%Handler_read_rnd_next';
+
+# Check that repeated NULL-scans are not cached (subq. is not correlated):
+delete from t2;
+insert into t2 values (NULL, 0),(NULL, 0), (NULL, 0), (NULL, 0);
+
+flush status;
+select oref, a, a in (select a from t1 where oref=t2.oref) Z from t2;
+show status like '%Handler_read%';
+select 'No key lookups, seq reads: 29= 5 reads from t2 + 4 * 6 reads from t1.' Z;
+
+drop table t1, t2;
+
+#
+# 3. Subquery handled with 'unique_index_subquery':
+#
+create table t1 (a int, b int, primary key (a));
+insert into t1 values (1,1), (3,1),(100,1);
+
+create table t2 (a int, b int);
+insert into t2 values (1,1),(2,1),(NULL,1),(NULL,0);
+
+select a,b, a in (select a from t1 where t1.b = t2.b) Z from t2 ;
+
+drop table t1, t2;
+
+#
+# 4. Subquery that is a join, with ref access
+#
+create table t1 (a int, b int, key(a));
+insert into t1 values
+ (0,0),(1,1),(2,2),(3,3),(4,4),(5,5),(6,6),(7,7),(8,8),(9,9);
+
+create table t2 like t1;
+insert into t2 select * from t1;
+update t2 set b=1;
+
+create table t3 (a int, oref int);
+insert into t3 values (1, 1), (NULL,1), (NULL,0);
+select a, oref,
+ t3.a in (select t1.a from t1, t2 where t1.b=t2.a and t2.b=t3.oref) Z
+from t3;
+
+# This must have trigcond in WHERE and HAVING:
+explain extended
+select a, oref,
+ t3.a in (select t1.a from t1, t2 where t1.b=t2.a and t2.b=t3.oref) Z
+from t3;
+
+drop table t1, t2, t3;
+