Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

executor: wrong results for in clause #23889

Closed
fzhedu opened this issue Apr 7, 2021 · 2 comments · Fixed by #23989
Closed

executor: wrong results for in clause #23889

fzhedu opened this issue Apr 7, 2021 · 2 comments · Fixed by #23989
Assignees
Labels
severity/critical sig/execution SIG execution type/bug The issue is confirmed as a bug.

Comments

@fzhedu
Copy link
Contributor

fzhedu commented Apr 7, 2021

Bug Report

Please answer these questions before submitting your issue. Thanks!

1. Minimal reproduce step (Required)

mysql -h172.16.5.85 -P52324 -uroot -D subquery_agg10000

2. What did you expect to see? (Required)

SELECT  ( table1 . `col_decimal` , table1 . `col_decimal` ) IN      (SELECT SUBQUERY3_t1 . `col_int` AS SUBQUERY3_field1 ,          SUM( SUBQUERY3_t2 . `col_int_not_null_key` ) AS SUBQUERY3_field2     FROM `DD` AS SUBQUERY3_t1 RIGHT OUTER     JOIN `F` AS SUBQUERY3_t2         ON (SUBQUERY3_t2 . `col_varchar_key` = SUBQUERY3_t1 . `col_varchar_64` )     GROUP BY  SUBQUERY3_field1 ) AS field3 FROM  `BB`  AS table1     group by 1;
+--------+
| field3 |
+--------+
|   NULL |
|      0 |
+--------+
2 rows in set (0.07 sec)
SELECT  ( 2, 2 ) NOT IN ( SELECT   SUBQUERY1_t1 . `col_tinyint` AS SUBQUERY1_field1 , SUBQUERY1_t1 . `col_tinyint` AS SUBQUERY1_field2 FROM `F` AS SUBQUERY1_t1 RIGHT OUTER JOIN `BB` AS SUBQUERY1_t2 ON (SUBQUERY1_t2 . `col_varchar_64` = SUBQUERY1_t1 . `col_varchar_key`  )  GROUP BY SUBQUERY1_field1 , SUBQUERY1_field2  ) AS field1 FROM `BB` AS table1 LEFT  JOIN (  SELECT   SUBQUERY2_t1 . * FROM `C` AS SUBQUERY2_t1 LEFT  JOIN `G` AS SUBQUERY2_t2 ON (SUBQUERY2_t2 . `col_char_64_not_null` = SUBQUERY2_t1 . `col_varchar_key`  )  ) AS table2 ON (table2 . `col_decimal_40_key` = table1 . `col_decimal_not_null_key`  ) WHERE  table1 . `col_varchar_64_not_null` <> SOME ( SELECT DISTINCT  SUBQUERY3_t1 . `col_char_64` AS SUBQUERY3_field1 FROM `L` AS SUBQUERY3_t1 INNER JOIN ( `T` AS SUBQUERY3_t2 INNER JOIN `E` AS SUBQUERY3_t3 ON (SUBQUERY3_t3 . `col_bigint_not_null` = SUBQUERY3_t2 . `pk`  )) ON (SUBQUERY3_t3 . `col_char_64` = SUBQUERY3_t2 . `col_varchar_key`  ) WHERE SUBQUERY3_t3 . `col_varchar_64_not_null` <= table1 . `col_varchar_64` AND SUBQUERY3_t1 . `col_decimal_40` >= table1 . `col_int` ) OR table1 . `col_varchar_key` = 'i' OR table1 . `pk` != table1 . `pk`   ;
+--------+
| field1 |
+--------+
|   NULL |
|   NULL |
|   NULL |
|   NULL |
|   NULL |
|   NULL |
+--------+
6 rows in set (0.04 sec)

3. What did you see instead (Required)

mysql> SELECT  ( table1 . `col_decimal` , table1 . `col_decimal` ) IN      (SELECT SUBQUERY3_t1 . `col_int` AS SUBQUERY3_field1 ,          SUM( SUBQUERY3_t2 . `col_int_not_null_key` ) AS SUBQUERY3_field2     FROM `DD` AS SUBQUERY3_t1 RIGHT OUTER     JOIN `F` AS SUBQUERY3_t2         ON (SUBQUERY3_t2 . `col_varchar_key` = SUBQUERY3_t1 . `col_varchar_64` )     GROUP BY  SUBQUERY3_field1 ) AS field3 FROM  `BB`  AS table1     group by 1;
+--------+
| field3 |
+--------+
|      0 |
+--------+
1 row in set (0.08 sec)
SELECT  ( 2, 2 ) NOT IN ( SELECT   SUBQUERY1_t1 . `col_tinyint` AS SUBQUERY1_field1 , SUBQUERY1_t1 . `col_tinyint` AS SUBQUERY1_field2 FROM `F` AS SUBQUERY1_t1 RIGHT OUTER JOIN `BB` AS SUBQUERY1_t2 ON (SUBQUERY1_t2 . `col_varchar_64` = SUBQUERY1_t1 . `col_varchar_key`  )  GROUP BY SUBQUERY1_field1 , SUBQUERY1_field2  ) AS field1 FROM `BB` AS table1 LEFT  JOIN (  SELECT   SUBQUERY2_t1 . * FROM `C` AS SUBQUERY2_t1 LEFT  JOIN `G` AS SUBQUERY2_t2 ON (SUBQUERY2_t2 . `col_char_64_not_null` = SUBQUERY2_t1 . `col_varchar_key`  )  ) AS table2 ON (table2 . `col_decimal_40_key` = table1 . `col_decimal_not_null_key`  ) WHERE  table1 . `col_varchar_64_not_null` <> SOME ( SELECT DISTINCT  SUBQUERY3_t1 . `col_char_64` AS SUBQUERY3_field1 FROM `L` AS SUBQUERY3_t1 INNER JOIN ( `T` AS SUBQUERY3_t2 INNER JOIN `E` AS SUBQUERY3_t3 ON (SUBQUERY3_t3 . `col_bigint_not_null` = SUBQUERY3_t2 . `pk`  )) ON (SUBQUERY3_t3 . `col_char_64` = SUBQUERY3_t2 . `col_varchar_key`  ) WHERE SUBQUERY3_t3 . `col_varchar_64_not_null` <= table1 . `col_varchar_64` AND SUBQUERY3_t1 . `col_decimal_40` >= table1 . `col_int` ) OR table1 . `col_varchar_key` = 'i' OR table1 . `pk` != table1 . `pk`   ;
+--------+
| field1 |
+--------+
|      1 |
|      1 |
|      1 |
|      1 |
|      1 |
|      1 |
+--------+
6 rows in set (1.72 sec)

4. What is your TiDB version? (Required)

master of nightly

@fzhedu fzhedu added the type/bug The issue is confirmed as a bug. label Apr 7, 2021
@jebter jebter added the sig/execution SIG execution label Apr 9, 2021
@wshwsh12 wshwsh12 self-assigned this Apr 12, 2021
@wshwsh12
Copy link
Contributor

wshwsh12 commented Apr 12, 2021

Minimal reproduction step:

create table test_decimal(col_decimal decimal(10,0));
insert into test_decimal values(null),(8);
create table test_t(a int(11), b decimal(32,0));
insert into test_t values(1,4),(2,4),(5,4),(7,4),(9,4);

SELECT  
( test_decimal . `col_decimal` , test_decimal . `col_decimal` ) 
IN      
( select * from test_t ) as field1
FROM  test_decimal;

In mysql:

+--------+
| field1 |
+--------+
|   NULL |
|      0 |
+--------+

In TiDB:

+--------+
| field1 |
+--------+
|      0 |
|      0 |
+--------+

The reason is ppdSolver will create a condition eq(test_t.b, cast(test_t.a, decimal(20,0) BINARY)) and EvalBool will return false instead of null.

@ti-srebot
Copy link
Contributor

Please edit this comment or add a new comment to complete the following information

Not a bug

  1. Remove the 'type/bug' label
  2. Add notes to indicate why it is not a bug

Duplicate bug

  1. Add the 'type/duplicate' label
  2. Add the link to the original bug

Bug

Note: Make Sure that 'component', and 'severity' labels are added
Example for how to fill out the template: #20100

1. Root Cause Analysis (RCA) (optional)

2. Symptom (optional)

3. All Trigger Conditions (optional)

4. Workaround (optional)

5. Affected versions

6. Fixed versions

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
severity/critical sig/execution SIG execution type/bug The issue is confirmed as a bug.
Projects
None yet
Development

Successfully merging a pull request may close this issue.

5 participants