Uploaded image for project: 'MariaDB Server'
  1. MariaDB Server
  2. MDEV-3746

LP:694443 - Wrong result with hash join and join_cache_level=6

    Details

    • Type: Bug
    • Status: Closed
    • Priority: Critical
    • Resolution: Fixed
    • Affects Version/s: None
    • Fix Version/s: None
    • Component/s: None
    • Labels:

      Description

      In maria-5.3 , the following query:

      SELECT STRAIGHT_JOIN t1.f2 FROM t1 JOIN t2 ON t1.f4 = t2.f5 WHERE ( t2.f1 OR t2.f2 ) AND t2.f3 IS NULL ;

      returns no rows even though 1 row matches the WHERE predicate and is returned by all other plans.

      explain:

      id select_type table type possible_keys key key_len ref rows Extra
      1 SIMPLE t1 ALL NULL NULL NULL NULL 2
      1 SIMPLE t2 ref f3 f3 5 const 1 Using where; Using join buffer (flat, BNLH join)

      test case:

      CREATE TABLE t1 (f2 int(11), f4 varchar(10)) ;
      INSERT IGNORE INTO t1 VALUES ('19','time'),('24','juabngoyrt');

      CREATE TABLE t2 (f5 varchar(10), f2 int(11), f1 int(11), f3 int(11), KEY (f3)) ;
      INSERT IGNORE INTO t2 VALUES ('time','4',NULL,NULL);

      SET SESSION join_cache_level=6;
      SET SESSION optimizer_switch='join_cache_bka=off';
      SELECT STRAIGHT_JOIN t1.f2 FROM t1 JOIN t2 ON t1.f4 = t2.f5 WHERE ( t2.f1 OR t2.f2 ) AND t2.f3 IS NULL ;
      EXPLAIN SELECT STRAIGHT_JOIN t1.f2 FROM t1 JOIN t2 ON t1.f4 = t2.f5 WHERE ( t2.f1 OR t2.f2 ) AND t2.f3 IS NULL ;

      SET SESSION join_cache_level=0;
      SET SESSION optimizer_switch='index_condition_pushdown=off';
      SELECT STRAIGHT_JOIN t1.f2 FROM t1 JOIN t2 ON t1.f4 = t2.f5 WHERE ( t2.f1 OR t2.f2 ) AND t2.f3 IS NULL ;

      Even though this particular test case includes join_cache_bka=off, the problematic query plan was also observed without having to force it.

        Gliffy Diagrams

          Attachments

            Activity

            Hide
            philipstoev Philip Stoev added a comment -

            Re: Wrong result with hash join and join_cache_level=6
            bzr version-info:

            revision-id: igor@askmonty.org-20101226025414-1opbueutu602o8eu
            date: 2010-12-25 18:54:14 -0800
            build-date: 2010-12-26 12:03:40 +0200
            revno: 2871
            branch-nick: maria-5.3

            Show
            philipstoev Philip Stoev added a comment - Re: Wrong result with hash join and join_cache_level=6 bzr version-info: revision-id: igor@askmonty.org-20101226025414-1opbueutu602o8eu date: 2010-12-25 18:54:14 -0800 build-date: 2010-12-26 12:03:40 +0200 revno: 2871 branch-nick: maria-5.3
            Hide
            igor Igor Babaev added a comment -

            Re: Wrong result with hash join and join_cache_level=6
            The bug can be reproduced with join_cache_level=4, without STRAIGHT_JOIN and
            with tables of a simpler structure:

            MariaDB [test]> CREATE TABLE t1 (a int PRIMARY KEY);
            Query OK, 0 rows affected (0.02 sec)

            MariaDB [test]> INSERT INTO t1 VALUES
            -> (7), (4), (9), (1), (3), (8), (2);
            Query OK, 7 rows affected (0.01 sec)
            Records: 7 Duplicates: 0 Warnings: 0

            MariaDB [test]> CREATE TABLE t2 (a int, b int, INDEX idx (a));
            Query OK, 0 rows affected (0.00 sec)

            MariaDB [test]> INSERT INTO t2 VALUES
            -> (NULL,10), (4,80), (7,70), (6,11), (7,90), (NULL,40),
            -> (4,77), (4,50), (NULL,41), (7,99), (7,88), (8,12),
            -> (1,21), (4,90), (7,91), (8,22), (6,92), (NULL,42),
            -> (2,78), (2,51), (1,43), (5,97), (5,89);
            Query OK, 23 rows affected (0.00 sec)
            Records: 23 Duplicates: 0 Warnings: 0

            MariaDB [test]>
            MariaDB [test]> SET SESSION join_cache_level = 1;
            Query OK, 0 rows affected (0.00 sec)

            MariaDB [test]> EXPLAIN
            -> SELECT * FROM t1,t2 WHERE t1.a < 3 and t2.a IS NULL;
            -------------------------------------------------------------------------------------+

            id select_type table type possible_keys key key_len ref rows Extra

            -------------------------------------------------------------------------------------+

            1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 3 Using where; Using index
            1 SIMPLE t2 ref idx idx 5 const 4 Using index condition

            -------------------------------------------------------------------------------------+
            2 rows in set (0.00 sec)

            MariaDB [test]> SELECT * FROM t1,t2 WHERE t1.a < 3 and t2.a IS NULL;
            -----------

            a a b

            -----------

            1 NULL 10
            1 NULL 40
            1 NULL 41
            1 NULL 42
            2 NULL 10
            2 NULL 40
            2 NULL 41
            2 NULL 42

            -----------
            8 rows in set (0.00 sec)

            MariaDB [test]> SET SESSION join_cache_level = 4;
            Query OK, 0 rows affected (0.00 sec)

            MariaDB [test]> EXPLAIN
            -> SELECT * FROM t1,t2 WHERE t1.a < 3 and t2.a IS NULL;
            -------------------------------------------------------------------------------------------------------------+

            id select_type table type possible_keys key key_len ref rows Extra

            -------------------------------------------------------------------------------------------------------------+

            1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 3 Using where; Using index
            1 SIMPLE t2 ref idx idx 5 const 4 Using where; Using join buffer (flat, BNLH join)

            -------------------------------------------------------------------------------------------------------------+
            2 rows in set (0.00 sec)

            MariaDB [test]> SELECT * FROM t1,t2 WHERE t1.a < 3 and t2.a IS NULL;
            Empty set (0.00 sec)

            Show
            igor Igor Babaev added a comment - Re: Wrong result with hash join and join_cache_level=6 The bug can be reproduced with join_cache_level=4, without STRAIGHT_JOIN and with tables of a simpler structure: MariaDB [test] > CREATE TABLE t1 (a int PRIMARY KEY); Query OK, 0 rows affected (0.02 sec) MariaDB [test] > INSERT INTO t1 VALUES -> (7), (4), (9), (1), (3), (8), (2); Query OK, 7 rows affected (0.01 sec) Records: 7 Duplicates: 0 Warnings: 0 MariaDB [test] > CREATE TABLE t2 (a int, b int, INDEX idx (a)); Query OK, 0 rows affected (0.00 sec) MariaDB [test] > INSERT INTO t2 VALUES -> (NULL,10), (4,80), (7,70), (6,11), (7,90), (NULL,40), -> (4,77), (4,50), (NULL,41), (7,99), (7,88), (8,12), -> (1,21), (4,90), (7,91), (8,22), (6,92), (NULL,42), -> (2,78), (2,51), (1,43), (5,97), (5,89); Query OK, 23 rows affected (0.00 sec) Records: 23 Duplicates: 0 Warnings: 0 MariaDB [test] > MariaDB [test] > SET SESSION join_cache_level = 1; Query OK, 0 rows affected (0.00 sec) MariaDB [test] > EXPLAIN -> SELECT * FROM t1,t2 WHERE t1.a < 3 and t2.a IS NULL; --- ----------- ----- ----- ------------- ------- ------- ----- ---- -------------------------+ id select_type table type possible_keys key key_len ref rows Extra --- ----------- ----- ----- ------------- ------- ------- ----- ---- -------------------------+ 1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 3 Using where; Using index 1 SIMPLE t2 ref idx idx 5 const 4 Using index condition --- ----------- ----- ----- ------------- ------- ------- ----- ---- -------------------------+ 2 rows in set (0.00 sec) MariaDB [test] > SELECT * FROM t1,t2 WHERE t1.a < 3 and t2.a IS NULL; -- ---- ----- a a b -- ---- ----- 1 NULL 10 1 NULL 40 1 NULL 41 1 NULL 42 2 NULL 10 2 NULL 40 2 NULL 41 2 NULL 42 -- ---- ----- 8 rows in set (0.00 sec) MariaDB [test] > SET SESSION join_cache_level = 4; Query OK, 0 rows affected (0.00 sec) MariaDB [test] > EXPLAIN -> SELECT * FROM t1,t2 WHERE t1.a < 3 and t2.a IS NULL; --- ----------- ----- ----- ------------- ------- ------- ----- ---- -------------------------------------------------+ id select_type table type possible_keys key key_len ref rows Extra --- ----------- ----- ----- ------------- ------- ------- ----- ---- -------------------------------------------------+ 1 SIMPLE t1 range PRIMARY PRIMARY 4 NULL 3 Using where; Using index 1 SIMPLE t2 ref idx idx 5 const 4 Using where; Using join buffer (flat, BNLH join) --- ----------- ----- ----- ------------- ------- ------- ----- ---- -------------------------------------------------+ 2 rows in set (0.00 sec) MariaDB [test] > SELECT * FROM t1,t2 WHERE t1.a < 3 and t2.a IS NULL; Empty set (0.00 sec)
            Hide
            ratzpo Rasmus Johansson added a comment -

            Launchpad bug id: 694443

            Show
            ratzpo Rasmus Johansson added a comment - Launchpad bug id: 694443

              People

              • Assignee:
                igor Igor Babaev
                Reporter:
                philipstoev Philip Stoev
              • Votes:
                0 Vote for this issue
                Watchers:
                0 Start watching this issue

                Dates

                • Created:
                  Updated:
                  Resolved: