diff --git a/dbcon/mysql/ha_in_sub.cpp b/dbcon/mysql/ha_in_sub.cpp index b57b78c56..c18088aee 100644 --- a/dbcon/mysql/ha_in_sub.cpp +++ b/dbcon/mysql/ha_in_sub.cpp @@ -266,7 +266,6 @@ void InSub::handleFunc(gp_walk_info* gwip, Item_func* func) if (cond->argument_list()->elements == 1) return; - // (cache=item or isnull(item)) case. remove "or isnull()" if (cond->argument_list()->elements == 2) { // don't know how to deal with this. don't think it's a fatal error either. @@ -278,35 +277,22 @@ void InSub::handleFunc(gp_walk_info* gwip, Item_func* func) if (!pt->left() || !pt->right()) return; - SimpleFilter* sf = dynamic_cast(pt->left()->data()); + SimpleFilter* lsf = dynamic_cast(pt->left()->data()); + SimpleFilter* rsf = dynamic_cast(pt->right()->data()); - //assert (sf && sf->op()->op() == execplan::OP_ISNULL); - if (!sf || sf->op()->op() != execplan::OP_ISNULL) + if (!lsf || !rsf) return; - delete sf; - sf = dynamic_cast(pt->right()->data()); - - //idbassert(sf && sf->op()->op() == execplan::OP_EQ); - if (!sf || sf->op()->op() != execplan::OP_EQ) - return; - - // set NULLMATCH for both operand. It's really a setting for the join. - // should only set NULLMATCH when the subtype is NOT_IN. for some IN subquery - // with aggregation column, MySQL inefficiently convert to: - // (cache=item or item is null) and item is not null, which is equivalent to - // cache = item. Do not set NULLMATCH for this case. - // Because we don't know IN or NOTIN yet, set candidate bit and switch to NULLMATCH - // later in handleNot function. - if (sf->lhs()->joinInfo() & JOIN_CORRELATED) - sf->lhs()->joinInfo(sf->lhs()->joinInfo() | JOIN_NULLMATCH_CANDIDATE); - - if (sf->rhs()->joinInfo() & JOIN_CORRELATED) - sf->rhs()->joinInfo(sf->rhs()->joinInfo() | JOIN_NULLMATCH_CANDIDATE); - - pt = pt->right(); - gwip->ptWorkStack.pop(); - gwip->ptWorkStack.push(pt); + // (a=b or isnull(item))/(a=b or isnotnull(item)) case. + // swap the lhs and rhs operands of the OR operator. + if ((lsf->op()->op() == execplan::OP_ISNULL || + lsf->op()->op() == execplan::OP_ISNOTNULL) && + rsf->op()->op() == execplan::OP_EQ) + { + ParseTree* temp = pt->left(); + pt->left(pt->right()); + pt->right(temp); + } } } else if (cond->functype() == Item_func::EQ_FUNC) diff --git a/mysql-test/columnstore/basic/r/mcol-4642.result b/mysql-test/columnstore/basic/r/mcol-4642.result new file mode 100644 index 000000000..d75bff19c --- /dev/null +++ b/mysql-test/columnstore/basic/r/mcol-4642.result @@ -0,0 +1,49 @@ +# +# MCOL-4642 NOT IN subquery containing an isnull in the OR predicate crashes server +# +DROP DATABASE IF EXISTS mcol4642; +CREATE DATABASE mcol4642; +USE mcol4642; +CREATE TABLE cs1 (a int); +INSERT INTO cs1 VALUES (1), (2), (3), (4), (null); +CREATE TABLE cs2 (b int, c int); +INSERT INTO cs2 VALUES (1, 100), (1, 101), (2, 200),(3, 300), (3, 301), (3, 302), (null, null); +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b is not null OR b is null); +a +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b is null OR b is not null); +a +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b is not null OR b is null); +a +1 +2 +3 +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b is null OR b is not null); +a +1 +2 +3 +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b=123 OR b is null); +a +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b is null OR b=123); +a +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b=123 OR b is null); +a +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b is null OR b=123); +a +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b=123 OR b is not null); +a +4 +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b is not null OR b=123); +a +4 +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b=123 OR b is not null); +a +1 +2 +3 +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b is not null OR b=123); +a +1 +2 +3 +DROP DATABASE mcol4642; diff --git a/mysql-test/columnstore/basic/t/mcol-4642.test b/mysql-test/columnstore/basic/t/mcol-4642.test new file mode 100644 index 000000000..794f76f54 --- /dev/null +++ b/mysql-test/columnstore/basic/t/mcol-4642.test @@ -0,0 +1,35 @@ +--source ../include/have_columnstore.inc +--source ctype_cmp_combinations.inc + +--echo # +--echo # MCOL-4642 NOT IN subquery containing an isnull in the OR predicate crashes server +--echo # + +--disable_warnings +DROP DATABASE IF EXISTS mcol4642; +--enable_warnings + +CREATE DATABASE mcol4642; +USE mcol4642; + +CREATE TABLE cs1 (a int); +INSERT INTO cs1 VALUES (1), (2), (3), (4), (null); +CREATE TABLE cs2 (b int, c int); +INSERT INTO cs2 VALUES (1, 100), (1, 101), (2, 200),(3, 300), (3, 301), (3, 302), (null, null); + +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b is not null OR b is null); +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b is null OR b is not null); +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b is not null OR b is null); +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b is null OR b is not null); + +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b=123 OR b is null); +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b is null OR b=123); +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b=123 OR b is null); +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b is null OR b=123); + +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b=123 OR b is not null); +SELECT * FROM cs1 WHERE a NOT IN (SELECT b FROM cs2 WHERE b is not null OR b=123); +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b=123 OR b is not null); +SELECT * FROM cs1 WHERE a IN (SELECT b FROM cs2 WHERE b is not null OR b=123); + +DROP DATABASE mcol4642;