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

LP:843874 - Wrong result with views + degenerate WHERE condition

    Details

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

      Description

      The following degenerate query:

      SELECT * FROM t1 RIGHT JOIN v2 ON t1.a = v2.a WHERE ( v2.b AND v2.b = v2.b );

      has the following EXPLAIN:

      1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables

      even though using a base table instead of a view returns the following result:

      a a b

      -----------------

      NULL dfcjsisnfe 9

      and has the following explain:

      1 SIMPLE t1 system NULL NULL NULL NULL 0 const row not found
      1 SIMPLE t2 system NULL NULL NULL NULL 1  

      The issue has also been observed with the following slightly less degenerate query:

      SELECT MAX( DISTINCT alias2 . `pk` ) AS field1 FROM C AS alias1 RIGHT JOIN view_DD AS alias2 ON alias1 . `col_varchar_10_utf8_key` = alias2 . `col_varchar_10_utf8_key` WHERE ( alias2 . `pk` NOT BETWEEN 1 AND ( 1 + 6 ) AND alias2 . `pk` = alias2 . `pk` ) ;

      optimizer switch:

      index_merge=on,index_merge_union=on,index_merge_sort_union=on,index_merge_intersection=on,index_merge_sort_intersection=off,index_condition_pushdown=off,derived_merge=off,derived_with_keys=off,firstmatch=off,loosescan=off,materialization=off,in_to_exists=on,semijoin=off,partial_match_rowid_merge=on,partial_match_table_scan=on,subquery_cache=off,mrr=off,mrr_cost_based=off,mrr_sort_keys=off,outer_join_with_cache=off,semijoin_with_cache=off,join_cache_incremental=on,join_cache_hashed=off,join_cache_bka=off,optimize_join_buffer_size=off,table_elimination=on

      bzr version-info
      revision-id: <email address hidden>
      date: 2011-09-06 20:59:29 +0400
      build-date: 2011-09-07 16:19:16 +0300
      revno: 3178
      branch-nick: maria-5.3

      Repeatable with maria-5.3. Not repeatable with maria-5.2, mysql-5.5

      test case:

      CREATE TABLE t1 ( a int) ;

      CREATE TABLE t2 ( a varchar(32), b int NOT NULL ) ;
      INSERT INTO t2 VALUES ('dfcjsisnfe',9)

      CREATE OR REPLACE VIEW v2 AS SELECT * FROM t2;
      SELECT * FROM t1 RIGHT JOIN v2 ON t1.a = v2.a WHERE v2.b AND v2.b = v2.b;
      SELECT * FROM t1 RIGHT JOIN t2 ON t1.a = t2.a WHERE t2.b AND t2.b = t2.b;

        Gliffy Diagrams

          Attachments

            Activity

            Hide
            philipstoev Philip Stoev added a comment -

            Re: Wrong result with views + degenerate WHERE condition
            Here is another example. Test case:

            CREATE TABLE t1 ( a int) ;

            CREATE TABLE t2 ( a int NOT NULL , b int, c varchar(32)) ;
            INSERT INTO t2 VALUES (8,2048393216,'cokycbnionsnwlt1');
            CREATE OR REPLACE VIEW v1 AS SELECT * FROM t1;
            CREATE OR REPLACE VIEW v2 AS SELECT * FROM t2;

            A query with base tables:
            SELECT * FROM t1 RIGHT JOIN t2 ON t1.a = t2.c WHERE (t2.b AND t2.a = 8);

            results in the following EXPLAIN EXTENDED:
            select ... from `test`.`t2` left join `test`.`t1` on((`test`.`t1`.`a` = `test`.`t2`.`c`)) where ((`test`.`t2`.`a` = 8) and `test`.`t2`.`b`);

            The same query with views:
            SELECT * FROM v1 RIGHT JOIN v2 ON v1.a = v2.c WHERE (v2.b AND v2.a = 8)

            results in the following EXPLAIN EXTENDED:
            select ... from `test`.`t2` join `test`.`t1` where ((`test`.`t2`.`a` = 8) and `test`.`t2`.`b` and (`test`.`t1`.`a` = `test`.`t2`.`c`));

            The outer join has been replaced by an inner join. The two queries return different results.

            Show
            philipstoev Philip Stoev added a comment - Re: Wrong result with views + degenerate WHERE condition Here is another example. Test case: CREATE TABLE t1 ( a int) ; CREATE TABLE t2 ( a int NOT NULL , b int, c varchar(32)) ; INSERT INTO t2 VALUES (8,2048393216,'cokycbnionsnwlt1'); CREATE OR REPLACE VIEW v1 AS SELECT * FROM t1; CREATE OR REPLACE VIEW v2 AS SELECT * FROM t2; A query with base tables: SELECT * FROM t1 RIGHT JOIN t2 ON t1.a = t2.c WHERE (t2.b AND t2.a = 8); results in the following EXPLAIN EXTENDED: select ... from `test`.`t2` left join `test`.`t1` on((`test`.`t1`.`a` = `test`.`t2`.`c`)) where ((`test`.`t2`.`a` = 8) and `test`.`t2`.`b`); The same query with views: SELECT * FROM v1 RIGHT JOIN v2 ON v1.a = v2.c WHERE (v2.b AND v2.a = 8) results in the following EXPLAIN EXTENDED: select ... from `test`.`t2` join `test`.`t1` where ((`test`.`t2`.`a` = 8) and `test`.`t2`.`b` and (`test`.`t1`.`a` = `test`.`t2`.`c`)); The outer join has been replaced by an inner join. The two queries return different results.
            Hide
            igor Igor Babaev added a comment -

            Re: Wrong result with views + degenerate WHERE condition
            This bug was fixed by the patch for LP bug #833600 (rev.3182).

            Show
            igor Igor Babaev added a comment - Re: Wrong result with views + degenerate WHERE condition This bug was fixed by the patch for LP bug #833600 (rev.3182).
            Hide
            ratzpo Rasmus Johansson added a comment -

            Launchpad bug id: 843874

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

              People

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

                Dates

                • Created:
                  Updated:
                  Resolved: