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

Wrong result for SELECT..WHERE varchar_column='a' AND CRC32(varchar_column)=3904355907

Details

    • Bug
    • Status: Closed (View Workflow)
    • Major
    • Resolution: Fixed
    • 5.5(EOL), 10.0(EOL), 10.1(EOL)
    • 10.1.7
    • Optimizer
    • None

    Description

      This script:

      DROP TABLE IF EXISTS t1;
      CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
      INSERT INTO t1 VALUES ('a'),('a ');
      SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE CRC32(a)=3904355907; 

      returns one row:

      +------+-----------+------------+
      | a    | LENGTH(a) | CRC32(a)   |
      +------+-----------+------------+
      | a    |         1 | 3904355907 |
      +------+-----------+------------+

      If I make the condition even stricter:

      SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE a='a' AND CRC32(a)=3904355907;

      it erroneously returns two rows:

      +------+-----------+------------+
      | a    | LENGTH(a) | CRC32(a)   |
      +------+-----------+------------+
      | a    |         1 | 3904355907 |
      | a    |         2 |  105998545 |
      +------+-----------+------------+

      This script demonstrates the same problem:

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

      It returns one row:

      +------+--------+
      | a    | HEX(a) |
      +------+--------+
      | a    | 61     |
      +------+--------+

      Now if I make the condition even stricter:

      SELECT *,HEX(a) FROM t1 WHERE a='a' AND HEX(a)='61';

      It returns two rows:

      +------+--------+
      | a    | HEX(a) |
      +------+--------+
      | a    | 61     |
      | a    | 6120   |
      +------+--------+

      A similar problem with trailing spaces:

      DROP TABLE IF EXISTS t1;
      CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
      INSERT INTO t1 VALUES ('a ');
      SELECT * FROM t1 WHERE a='a';
      SELECT * FROM t1 WHERE LENGTH(a)=2;
      SELECT * FROM t1 WHERE a='a' AND LENGTH(a)=2;

      The first and the second query correctly return one row. The third query erroneously returns no rows.

      Attachments

        Issue Links

          Activity

            bar Alexander Barkov created issue -
            bar Alexander Barkov made changes -
            Field Original Value New Value
            Description This script:
            {code}
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE CRC32(a)=3904355907;
            {code}
            returns one row:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            +------+-----------+------------+
            {noformat}

            If I make the condition even stricter:
            {code}
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE a='a' AND CRC32(a)=3904355907;
            {code}
            it erroneously returns two rows:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            | a | 2 | 105998545 |
            +------+-----------+------------+
            {noformat}
            This script:
            {code}
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE CRC32(a)=3904355907;
            {code}
            returns one row:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            +------+-----------+------------+
            {noformat}

            If I make the condition even stricter:
            {code}
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE a='a' AND CRC32(a)=3904355907;
            {code}
            it erroneously returns two rows:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            | a | 2 | 105998545 |
            +------+-----------+------------+
            {noformat}


            This script demonstrates the same problem:
            {code}
            SET NAMES latin1;
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, HEX(a) FROM t1 WHERE HEX(a)='61';
            {code}
            It returns one row:
            {noformat}
            +------+--------+
            | a | HEX(a) |
            +------+--------+
            | a | 61 |
            +------+--------+
            {noformat}
            Now if I make the condition even stricter:
            {code}
            SELECT *,HEX(a) FROM t1 WHERE a='a' AND HEX(a)='61';
            {code}
            It returns two rows:
            {noformat}
            +------+--------+
            | a | HEX(a) |
            +------+--------+
            | a | 61 |
            | a | 6120 |
            +------+--------+
            {noformat}
            bar Alexander Barkov made changes -
            Summary Wrong result for SELECT..WHERE WHERE a='a' AND CRC32(a)=3904355907 Wrong result for SELECT..WHERE WHERE varchar_column='a' AND CRC32(varchar_column)=3904355907
            bar Alexander Barkov made changes -
            Summary Wrong result for SELECT..WHERE WHERE varchar_column='a' AND CRC32(varchar_column)=3904355907 Wrong result for SELECT..WHERE varchar_column='a' AND CRC32(varchar_column)=3904355907
            bar Alexander Barkov made changes -
            Description This script:
            {code}
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE CRC32(a)=3904355907;
            {code}
            returns one row:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            +------+-----------+------------+
            {noformat}

            If I make the condition even stricter:
            {code}
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE a='a' AND CRC32(a)=3904355907;
            {code}
            it erroneously returns two rows:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            | a | 2 | 105998545 |
            +------+-----------+------------+
            {noformat}


            This script demonstrates the same problem:
            {code}
            SET NAMES latin1;
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, HEX(a) FROM t1 WHERE HEX(a)='61';
            {code}
            It returns one row:
            {noformat}
            +------+--------+
            | a | HEX(a) |
            +------+--------+
            | a | 61 |
            +------+--------+
            {noformat}
            Now if I make the condition even stricter:
            {code}
            SELECT *,HEX(a) FROM t1 WHERE a='a' AND HEX(a)='61';
            {code}
            It returns two rows:
            {noformat}
            +------+--------+
            | a | HEX(a) |
            +------+--------+
            | a | 61 |
            | a | 6120 |
            +------+--------+
            {noformat}
            This script:
            {code}
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE CRC32(a)=3904355907;
            {code}
            returns one row:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            +------+-----------+------------+
            {noformat}

            If I make the condition even stricter:
            {code}
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE a='a' AND CRC32(a)=3904355907;
            {code}
            it erroneously returns two rows:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            | a | 2 | 105998545 |
            +------+-----------+------------+
            {noformat}


            This script demonstrates the same problem:
            {code}
            SET NAMES latin1;
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, HEX(a) FROM t1 WHERE HEX(a)='61';
            {code}
            It returns one row:
            {noformat}
            +------+--------+
            | a | HEX(a) |
            +------+--------+
            | a | 61 |
            +------+--------+
            {noformat}
            Now if I make the condition even stricter:
            {code}
            SELECT *,HEX(a) FROM t1 WHERE a='a' AND HEX(a)='61';
            {code}
            It returns two rows:
            {noformat}
            +------+--------+
            | a | HEX(a) |
            +------+--------+
            | a | 61 |
            | a | 6120 |
            +------+--------+
            {noformat}


            A similar problem with trailing spaces:
            {code}
            bar Alexander Barkov made changes -
            Description This script:
            {code}
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE CRC32(a)=3904355907;
            {code}
            returns one row:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            +------+-----------+------------+
            {noformat}

            If I make the condition even stricter:
            {code}
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE a='a' AND CRC32(a)=3904355907;
            {code}
            it erroneously returns two rows:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            | a | 2 | 105998545 |
            +------+-----------+------------+
            {noformat}


            This script demonstrates the same problem:
            {code}
            SET NAMES latin1;
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, HEX(a) FROM t1 WHERE HEX(a)='61';
            {code}
            It returns one row:
            {noformat}
            +------+--------+
            | a | HEX(a) |
            +------+--------+
            | a | 61 |
            +------+--------+
            {noformat}
            Now if I make the condition even stricter:
            {code}
            SELECT *,HEX(a) FROM t1 WHERE a='a' AND HEX(a)='61';
            {code}
            It returns two rows:
            {noformat}
            +------+--------+
            | a | HEX(a) |
            +------+--------+
            | a | 61 |
            | a | 6120 |
            +------+--------+
            {noformat}


            A similar problem with trailing spaces:
            {code}
            This script:
            {code}
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE CRC32(a)=3904355907;
            {code}
            returns one row:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            +------+-----------+------------+
            {noformat}

            If I make the condition even stricter:
            {code}
            SELECT a, LENGTH(a), CRC32(a) FROM t1 WHERE a='a' AND CRC32(a)=3904355907;
            {code}
            it erroneously returns two rows:
            {noformat}
            +------+-----------+------------+
            | a | LENGTH(a) | CRC32(a) |
            +------+-----------+------------+
            | a | 1 | 3904355907 |
            | a | 2 | 105998545 |
            +------+-----------+------------+
            {noformat}


            This script demonstrates the same problem:
            {code}
            SET NAMES latin1;
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a'),('a ');
            SELECT a, HEX(a) FROM t1 WHERE HEX(a)='61';
            {code}
            It returns one row:
            {noformat}
            +------+--------+
            | a | HEX(a) |
            +------+--------+
            | a | 61 |
            +------+--------+
            {noformat}
            Now if I make the condition even stricter:
            {code}
            SELECT *,HEX(a) FROM t1 WHERE a='a' AND HEX(a)='61';
            {code}
            It returns two rows:
            {noformat}
            +------+--------+
            | a | HEX(a) |
            +------+--------+
            | a | 61 |
            | a | 6120 |
            +------+--------+
            {noformat}


            A similar problem with trailing spaces:
            {code}
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARCHAR(10) COLLATE latin1_bin);
            INSERT INTO t1 VALUES ('a ');
            SELECT * FROM t1 WHERE a='a';
            SELECT * FROM t1 WHERE LENGTH(a)=2;
            SELECT * FROM t1 WHERE a='a' AND LENGTH(a)=2;
            {code}
            The first and the second query correctly return one row. The third query erroneously returns no rows.
            bar Alexander Barkov made changes -
            bar Alexander Barkov made changes -
            Comment [ Another related example:
            {code}
            DROP TABLE IF EXISTS t1;
            CREATE TABLE t1 (a VARBINARY(10));
            INSERT INTO t1 VALUES ('a');
            SELECT * FROM t1 WHERE COLLATION(a)='binary';
            SELECT * FROM t1 WHERE a='a';
            {code}
            The two SELECT queries return one row.

            Now if I join both conditions using AND in the same query:
            {code}
            SELECT * FROM t1 WHERE COLLATION(a)='binary' AND a='a';
            {code}
            It returns empty set.
            ]
            bar Alexander Barkov made changes -
            Fix Version/s 10.1.7 [ 19604 ]
            Fix Version/s 10.1 [ 16100 ]
            Resolution Fixed [ 1 ]
            Status Open [ 1 ] Closed [ 6 ]
            bar Alexander Barkov made changes -
            serg Sergei Golubchik made changes -
            Workflow MariaDB v3 [ 71239 ] MariaDB v4 [ 149529 ]

            People

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

              Dates

                Created:
                Updated:
                Resolved:

                Git Integration

                  Error rendering 'com.xiplink.jira.git.jira_git_plugin:git-issue-webpanel'. Please contact your Jira administrators.