Details

    • Bug
    • Status: Closed (View Workflow)
    • Major
    • Resolution: Fixed
    • 5.5(EOL), 10.0(EOL), 10.1(EOL), 10.2(EOL), 10.3(EOL), 10.4(EOL)
    • 10.4.0
    • Data types
    • None

    Description

      This scalar query respects unsigned_flag difference for 18446744073709551615 and -1, goes through val_decimal() and correctly returns 0:

      SELECT 18446744073709551615 IN (18446744073709551614,-1);
      

      +---------------------------------------------------+
      | 18446744073709551615 IN (18446744073709551614,-1) |
      +---------------------------------------------------+
      |                                                 0 |
      +---------------------------------------------------+
      

      A similar query with ROW() erroneously returns 1:

      SELECT (18446744073709551615,0) IN ((18446744073709551614,0),(-1,0));
      

      +---------------------------------------------------------------+
      | (18446744073709551615,0) IN ((18446744073709551614,0),(-1,0)) |
      +---------------------------------------------------------------+
      |                                                             1 |
      +---------------------------------------------------------------+
      

      It ignores unsigned_flag, goes through val_int() and treats 18446744073709551615 and -1 as same values.

      This scalar query correctly returns an error:

      SELECT 1=POINT(1,1);
      

      ERROR 4078 (HY000): Illegal parameter data types int and geometry for operation '='
      

      A similar ROW query erroneously returns a result with a warning:

      SELECT (1,0) IN ((POINT(1,1),0),(0,0));
      SHOW WARNINGS;
      

      +---------------------------------+
      | (1,0) IN ((POINT(1,1),0),(0,0)) |
      +---------------------------------+
      |                               0 |
      +---------------------------------+
      +---------+------+-------------------------------------------------------------------------------------------------------------------------------------+
      | Level   | Code | Message                                                                                                                             |
      +---------+------+-------------------------------------------------------------------------------------------------------------------------------------+
      | Warning | 1292 | Truncated incorrect INTEGER value: '\x00\x00\x00\x00\x01\x01\x00\x00\x00\x00\x00\x00\x00\x00\x00\xF0?\x00\x00\x00\x00\x00\x00\xF0?' |
      +---------+------+-------------------------------------------------------------------------------------------------------------------------------------+
      

      It's wrong, the expected behavior is to return an error, like a similar scalar query does.

      If I put POINT(1,1) to a deeper level, it also erroneously returns a result with the same warning:

      SELECT (1,(0,0)) IN ((1,(POINT(1,1),0)),(0,(0,0)));
      

      +---------------------------------------------+
      | (1,(0,0)) IN ((1,(POINT(1,1),0)),(0,(0,0))) |
      +---------------------------------------------+
      |                                           1 |
      +---------------------------------------------+
      

      The expected behavior is to return an error.

      Attachments

        Issue Links

          Activity

            A similar problem is repeatable when mixing a string and a number:

            According to MariaDB comparison rules, a string and a number are compared as DOUBLE. This script correctly follows this rule:

            SELECT '0x'=0;
            SHOW WARNINGS;
            

            +--------+
            | '0x'=0 |
            +--------+
            |      1 |
            +--------+
            +---------+------+----------------------------------------+
            | Level   | Code | Message                                |
            +---------+------+----------------------------------------+
            | Warning | 1292 | Truncated incorrect DOUBLE value: '0x' |
            +---------+------+----------------------------------------+
            

            Notice:

            • there is a warning because '0x' was trucated during string-to->double conversion
            • string '0x' was converted to double 0
            • the comparison returned TRUE

            This script produced exactly the same output:

            SELECT '0x' IN (0);
            SHOW WARNINGS;
            

            So does this script, using IN with one value:

            SELECT '0x' IN (0);
            SHOW WARNINGS;
            

            So does this script, using IN with two values:

            SELECT '0x' IN (0,1);
            SHOW WARNINGS;
            

            So does this script, using IN with ROW with one value:

            SELECT ('0x',1) IN ((0,1));
            

            Now if use IN with ROW with more than one values:

            SELECT ('0x',1) IN ((0,1),(1,1));
            

            +---------------------------+
            | ('0x',1) IN ((0,1),(1,1)) |
            +---------------------------+
            |                         0 |
            +---------------------------+
            

            it returns FALSE with no warnings.

            bar Alexander Barkov added a comment - A similar problem is repeatable when mixing a string and a number: According to MariaDB comparison rules, a string and a number are compared as DOUBLE. This script correctly follows this rule: SELECT '0x' =0; SHOW WARNINGS; +--------+ | '0x'=0 | +--------+ | 1 | +--------+ +---------+------+----------------------------------------+ | Level | Code | Message | +---------+------+----------------------------------------+ | Warning | 1292 | Truncated incorrect DOUBLE value: '0x' | +---------+------+----------------------------------------+ Notice: there is a warning because '0x' was trucated during string-to->double conversion string '0x' was converted to double 0 the comparison returned TRUE This script produced exactly the same output: SELECT '0x' IN (0); SHOW WARNINGS; So does this script, using IN with one value: SELECT '0x' IN (0); SHOW WARNINGS; So does this script, using IN with two values: SELECT '0x' IN (0,1); SHOW WARNINGS; So does this script, using IN with ROW with one value: SELECT ( '0x' ,1) IN ((0,1)); Now if use IN with ROW with more than one values: SELECT ( '0x' ,1) IN ((0,1),(1,1)); +---------------------------+ | ('0x',1) IN ((0,1),(1,1)) | +---------------------------+ | 0 | +---------------------------+ it returns FALSE with no warnings.

            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.