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

Wrong result for SELECT..WHERE a='a' AND a='a' COLLATE latin1_bin

    Details

      Description

      This bug is similar to http://bugs.mysql.com/bug.php?id=5134
      Note, the patch for MySQL bug#5134 fixed only a particular case of the problem when the BINARY keyword is used. The problem is in fact more general.

      This script:

      SET NAMES latin1;
      DROP TABLE IF EXISTS t1;
      CREATE TABLE t1 (a CHAR(10));
      INSERT INTO t1 VALUES ('a'),('A');
      SELECT * FROM t1 WHERE a = 'a' COLLATE latin1_bin;
      

      correctly returns one row:

      +------+
      | a    |
      +------+
      | a    |
      +------+
      

      Now if I add an extra part into the condition:

      SELECT * FROM t1 WHERE a='a' AND a='a' COLLATE latin1_bin;
      

      it returns two rows:

      +------+
      | a    |
      +------+
      | a    |
      | A    |
      +------+
      

      The expected result is to return one row in both cases.

      The problem happens because "AND a='a' COLLATE latin1_bin" gets erroneously replaced to "AND 'a'='a' COLLATE latin1_bin" which is further evaluates to TRUE and gets removed from the WHERE condition. So, the query gets rewritten to:

      SELECT * FROM t1 WHERE a='a';
      

      The method which actually replaces the field to the constant is Item_field::equal_fields_propagator() in item.cc.

      This condition is not strict enough:

        if (!item || !has_compatible_context(item))
          item= this;
      

      It should also take into account the collations of the two operations that the field "a" appears in.

        Gliffy Diagrams

          Attachments

            Issue Links

              Activity

              Hide
              bar Alexander Barkov added a comment - - edited

              Another example:

              SET NAMES latin1;
              DROP TABLE IF EXISTS t1;
              CREATE TABLE t1 (a VARCHAR(10) CHARACTER SET latin1 COLLATE latin1_swedish_ci);
              INSERT INTO t1 VALUES ('a'),('A');
              SELECT * FROM t1 WHERE a='a' COLLATE latin1_bin;
              SELECT * FROM t1 WHERE a='A' COLLATE latin1_swedish_ci;
              

              The above script returns one row in the first SELECT and two rows in the second SELECT:

              +------+
              | a    |
              +------+
              | a    |
              +------+
              1 row in set (0.00 sec)
              
              +------+
              | a    |
              +------+
              | a    |
              | A    |
              +------+
              2 rows in set (0.00 sec)
              

              Now if I join the above two condition using AND:

              SELECT * FROM t1 WHERE a='a' COLLATE latin1_bin AND a='A' COLLATE latin1_swedish_ci;
              

              I get empty set. This is wrong. The expected result is to return one row, the same result as in the first SELECT.

              Show
              bar Alexander Barkov added a comment - - edited Another example: SET NAMES latin1; DROP TABLE IF EXISTS t1; CREATE TABLE t1 (a VARCHAR(10) CHARACTER SET latin1 COLLATE latin1_swedish_ci); INSERT INTO t1 VALUES ('a'),('A'); SELECT * FROM t1 WHERE a='a' COLLATE latin1_bin; SELECT * FROM t1 WHERE a='A' COLLATE latin1_swedish_ci; The above script returns one row in the first SELECT and two rows in the second SELECT: +------+ | a | +------+ | a | +------+ 1 row in set (0.00 sec) +------+ | a | +------+ | a | | A | +------+ 2 rows in set (0.00 sec) Now if I join the above two condition using AND: SELECT * FROM t1 WHERE a='a' COLLATE latin1_bin AND a='A' COLLATE latin1_swedish_ci; I get empty set. This is wrong. The expected result is to return one row, the same result as in the first SELECT.
              Hide
              bar Alexander Barkov added a comment -

              The problem is repeatable in MySQL-5.7.8

              Show
              bar Alexander Barkov added a comment - The problem is repeatable in MySQL-5.7.8

                People

                • Assignee:
                  bar Alexander Barkov
                  Reporter:
                  bar Alexander Barkov
                • Votes:
                  0 Vote for this issue
                  Watchers:
                  1 Start watching this issue

                  Dates

                  • Created:
                    Updated:
                    Resolved: