From 0695f1ea1af1a30ada20a332b4aa2e93d2f2cfd2 Mon Sep 17 00:00:00 2001 From: Ti Chi Robot Date: Wed, 8 May 2024 20:07:08 +0800 Subject: [PATCH] planner: fix the issue about simplify outer join to inner join (#51750) (#53099) close pingcap/tidb#51560 --- planner/core/rule_predicate_push_down.go | 8 - .../core/issuetest/planner_issue.result | 362 ++++++++++++++++++ .../planner/core/issuetest/planner_issue.test | 214 +++++++++++ 3 files changed, 576 insertions(+), 8 deletions(-) create mode 100644 tests/integrationtest/r/planner/core/issuetest/planner_issue.result create mode 100644 tests/integrationtest/t/planner/core/issuetest/planner_issue.test diff --git a/planner/core/rule_predicate_push_down.go b/planner/core/rule_predicate_push_down.go index a0f9a7dd367df..68f602adb8240 100644 --- a/planner/core/rule_predicate_push_down.go +++ b/planner/core/rule_predicate_push_down.go @@ -399,14 +399,6 @@ func simplifyOuterJoin(p *LogicalJoin, predicates []expression.Expression) { innerTable, outerTable = outerTable, innerTable } - // first simplify embedded outer join. - if innerPlan, ok := innerTable.(*LogicalJoin); ok { - simplifyOuterJoin(innerPlan, predicates) - } - if outerPlan, ok := outerTable.(*LogicalJoin); ok { - simplifyOuterJoin(outerPlan, predicates) - } - if p.JoinType == InnerJoin { return } diff --git a/tests/integrationtest/r/planner/core/issuetest/planner_issue.result b/tests/integrationtest/r/planner/core/issuetest/planner_issue.result new file mode 100644 index 0000000000000..b7a0a40154fd7 --- /dev/null +++ b/tests/integrationtest/r/planner/core/issuetest/planner_issue.result @@ -0,0 +1,362 @@ +CREATE TABLE aa311c3c ( +57fd8d09 year(4) DEFAULT '1913', +afbdd7c3 char(220) DEFAULT 'gakkl6occ0yd2jmhi2qxog8szibtcqwxyxmga3hp4ktszjplmg3rjvu8v6lgn9q6hva2lekhw6napjejbut6svsr8q2j8w8rc551e5vq', +43b06e99 date NOT NULL DEFAULT '3403-10-08', +b80b3746 tinyint(4) NOT NULL DEFAULT '34', +6302d8ac timestamp DEFAULT '2004-04-01 18:21:18', +PRIMARY KEY (43b06e99,b80b3746) /*T![clustered_index] CLUSTERED */, +KEY 3080c821 (57fd8d09,43b06e99,b80b3746), +KEY a9af33a4 (57fd8d09,b80b3746,43b06e99), +KEY 464b386e (b80b3746), +KEY 19dc3c2d (57fd8d09) +) ENGINE=InnoDB DEFAULT CHARSET=ascii COLLATE=ascii_bin COMMENT='320f8401'; +explain select /*+ use_index_merge( `aa311c3c` ) */ `aa311c3c`.`43b06e99` as r0 , `aa311c3c`.`6302d8ac` as r1 from `aa311c3c` where IsNull( `aa311c3c`.`b80b3746` ) or not( `aa311c3c`.`57fd8d09` >= '2008' ) order by r0,r1 limit 95; +id estRows task access object operator info +Projection_7 95.00 root planner__core__issuetest__planner_issue.aa311c3c.43b06e99, planner__core__issuetest__planner_issue.aa311c3c.6302d8ac +└─TopN_9 95.00 root planner__core__issuetest__planner_issue.aa311c3c.43b06e99, planner__core__issuetest__planner_issue.aa311c3c.6302d8ac, offset:0, count:95 + └─IndexMerge_17 95.00 root type: union + ├─TableFullScan_13(Build) 0.00 cop[tikv] table:aa311c3c keep order:false, stats:pseudo + ├─IndexRangeScan_14(Build) 3323.33 cop[tikv] table:aa311c3c, index:3080c821(57fd8d09, 43b06e99, b80b3746) range:[-inf,2008), keep order:false, stats:pseudo + └─TopN_16(Probe) 95.00 cop[tikv] planner__core__issuetest__planner_issue.aa311c3c.43b06e99, planner__core__issuetest__planner_issue.aa311c3c.6302d8ac, offset:0, count:95 + └─TableRowIDScan_15 3323.33 cop[tikv] table:aa311c3c keep order:false, stats:pseudo +CREATE TABLE t1(id int,col1 varchar(10),col2 varchar(10),col3 varchar(10)); +CREATE TABLE t2(id int,col1 varchar(10),col2 varchar(10),col3 varchar(10)); +INSERT INTO t1 values(1,NULL,NULL,null),(2,NULL,NULL,null),(3,NULL,NULL,null); +INSERT INTO t2 values(1,'a','aa','aaa'),(2,'b','bb','bbb'),(3,'c','cc','ccc'); +WITH tmp AS (SELECT t2.* FROM t2) select (SELECT tmp.col1 FROM tmp WHERE tmp.id=t1.id ) col1, (SELECT tmp.col2 FROM tmp WHERE tmp.id=t1.id ) col2, (SELECT tmp.col3 FROM tmp WHERE tmp.id=t1.id ) col3 from t1; +col1 col2 col3 +a aa aaa +b bb bbb +c cc ccc +set tidb_enable_index_merge=on; +drop table if exists t; +create table t(a int, b int, index idx_a(a), index idx_b(b)); +set @@session.sql_select_limit=3; +explain format = 'brief' select * from t where a = 1 or b = 1; +id estRows task access object operator info +IndexMerge 3.00 root type: union, limit embedded(offset:0, count:3) +├─Limit(Build) 1.50 cop[tikv] offset:0, count:3 +│ └─IndexRangeScan 1.50 cop[tikv] table:t, index:idx_a(a) range:[1,1], keep order:false, stats:pseudo +├─Limit(Build) 1.50 cop[tikv] offset:0, count:3 +│ └─IndexRangeScan 1.50 cop[tikv] table:t, index:idx_b(b) range:[1,1], keep order:false, stats:pseudo +└─TableRowIDScan(Probe) 3.00 cop[tikv] table:t keep order:false, stats:pseudo +explain format = 'brief' select /*+ use_index_merge(t) */ * from t where a = 1 or b = 1; +id estRows task access object operator info +IndexMerge 3.00 root type: union, limit embedded(offset:0, count:3) +├─Limit(Build) 1.50 cop[tikv] offset:0, count:3 +│ └─IndexRangeScan 1.50 cop[tikv] table:t, index:idx_a(a) range:[1,1], keep order:false, stats:pseudo +├─Limit(Build) 1.50 cop[tikv] offset:0, count:3 +│ └─IndexRangeScan 1.50 cop[tikv] table:t, index:idx_b(b) range:[1,1], keep order:false, stats:pseudo +└─TableRowIDScan(Probe) 3.00 cop[tikv] table:t keep order:false, stats:pseudo +set @@session.sql_select_limit=18446744073709551615; +explain format = 'brief' select * from t where a = 1 or b = 1; +id estRows task access object operator info +IndexMerge 19.99 root type: union +├─IndexRangeScan(Build) 10.00 cop[tikv] table:t, index:idx_a(a) range:[1,1], keep order:false, stats:pseudo +├─IndexRangeScan(Build) 10.00 cop[tikv] table:t, index:idx_b(b) range:[1,1], keep order:false, stats:pseudo +└─TableRowIDScan(Probe) 19.99 cop[tikv] table:t keep order:false, stats:pseudo +explain format = 'brief' select * from t where a = 1 or b = 1 limit 3; +id estRows task access object operator info +IndexMerge 3.00 root type: union, limit embedded(offset:0, count:3) +├─Limit(Build) 1.50 cop[tikv] offset:0, count:3 +│ └─IndexRangeScan 1.50 cop[tikv] table:t, index:idx_a(a) range:[1,1], keep order:false, stats:pseudo +├─Limit(Build) 1.50 cop[tikv] offset:0, count:3 +│ └─IndexRangeScan 1.50 cop[tikv] table:t, index:idx_b(b) range:[1,1], keep order:false, stats:pseudo +└─TableRowIDScan(Probe) 3.00 cop[tikv] table:t keep order:false, stats:pseudo +drop table if exists t1, t2; +CREATE TABLE t1(id int,col1 varchar(10),col2 varchar(10),col3 varchar(10)); +CREATE TABLE t2(id int,col1 varchar(10),col2 varchar(10),col3 varchar(10)); +INSERT INTO t1 values(1,NULL,NULL,null),(2,NULL,NULL,null),(3,NULL,NULL,null); +INSERT INTO t2 values(1,'a','aa','aaa'),(2,'b','bb','bbb'),(3,'c','cc','ccc'); +WITH tmp AS (SELECT t2.* FROM t2) SELECT * FROM t1 WHERE t1.id = (select id from tmp where id = 1) or t1.id = (select id from tmp where id = 2) or t1.id = (select id from tmp where id = 3); +id col1 col2 col3 +1 NULL NULL NULL +2 NULL NULL NULL +3 NULL NULL NULL +drop table if exists t1, t2; +CREATE TABLE t1 (a INT, b INT); +CREATE TABLE t2 (a INT, b INT); +INSERT INTO t1 VALUES (1, 1); +INSERT INTO t2 VALUES (1, 1); +SELECT one.a, one.b as b2 FROM t1 one ORDER BY (SELECT two.b FROM t2 two WHERE two.a = one.b); +a b2 +1 1 +CREATE TABLE ads_txn ( +`cusno` varchar(10) NOT NULL, +`txn_dt` varchar(8) NOT NULL, +`unn_trno` decimal(22,0) NOT NULL, +`aml_cntpr_accno` varchar(64) DEFAULT NULL, +`acpayr_accno` varchar(35) DEFAULT NULL, +PRIMARY KEY (`cusno`,`txn_dt`,`unn_trno`) NONCLUSTERED +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +PARTITION BY LIST COLUMNS(`txn_dt`) +(PARTITION `p20000101` VALUES IN ('20000101'), +PARTITION `p20220101` VALUES IN ('20220101'), +PARTITION `p20230516` VALUES IN ('20230516')); +analyze table ads_txn; +set autocommit=OFF; +explain update ads_txn s set aml_cntpr_accno = trim(acpayr_accno) where s._tidb_rowid between 1 and 100000; +id estRows task access object operator info +Update_5 N/A root N/A +└─Projection_6 8000.00 root planner__core__issuetest__planner_issue.ads_txn.cusno, planner__core__issuetest__planner_issue.ads_txn.txn_dt, planner__core__issuetest__planner_issue.ads_txn.unn_trno, planner__core__issuetest__planner_issue.ads_txn.aml_cntpr_accno, planner__core__issuetest__planner_issue.ads_txn.acpayr_accno, planner__core__issuetest__planner_issue.ads_txn._tidb_rowid + └─SelectLock_7 8000.00 root for update 0 + └─TableReader_9 10000.00 root partition:all data:TableRangeScan_8 + └─TableRangeScan_8 10000.00 cop[tikv] table:s range:[1,100000], keep order:false, stats:pseudo +CREATE TABLE tb1 (cid INT, code INT, class VARCHAR(10)); +CREATE TABLE tb2 (cid INT, code INT, class VARCHAR(10)); +UPDATE tb1, (SELECT code AS cid, code, MAX(class) AS class FROM tb2 GROUP BY code) tb3 SET tb1.cid = tb3.cid, tb1.code = tb3.code, tb1.class = tb3.class; +CREATE TEMPORARY TABLE v0(v1 int); +INSERT INTO v0 WITH ta2 AS (TABLE v0) TABLE ta2 FOR UPDATE OF ta2; +create table tbl_39(col_239 year(4) not null default '2009', primary key(col_239), unique key idx_223(col_239), key idx_224(col_239)); +insert into tbl_39 values (1994),(1995),(1996),(1997); +explain select /*+ use_index_merge( tbl_39) */ col_239 from tbl_39 where not( tbl_39.col_239 not in ( '1994' ) ) and tbl_39.col_239 not in ( '2004' , '2010' , '2010' ) or not( tbl_39.col_239 <= '1996' ) and not( tbl_39.col_239 between '2026' and '2011' ) order by tbl_39.col_239 limit 382; +id estRows task access object operator info +Projection_8 382.00 root planner__core__issuetest__planner_issue.tbl_39.col_239 +└─Limit_15 382.00 root offset:0, count:382 + └─UnionScan_23 382.00 root or(and(not(not(eq(planner__core__issuetest__planner_issue.tbl_39.col_239, 1994))), not(in(planner__core__issuetest__planner_issue.tbl_39.col_239, 2004, 2010, 2010))), and(not(le(planner__core__issuetest__planner_issue.tbl_39.col_239, 1996)), not(and(ge(cast(planner__core__issuetest__planner_issue.tbl_39.col_239, double UNSIGNED BINARY), 2026), le(cast(planner__core__issuetest__planner_issue.tbl_39.col_239, double UNSIGNED BINARY), 2011))))) + └─IndexMerge_29 382.00 root type: union + ├─Selection_25(Build) 0.05 cop[tikv] not(in(planner__core__issuetest__planner_issue.tbl_39.col_239, 2004, 2010, 2010)) + │ └─IndexRangeScan_24 0.14 cop[tikv] table:tbl_39, index:PRIMARY(col_239) range:[1994,1994], keep order:true, stats:pseudo + ├─Selection_27(Build) 458.26 cop[tikv] or(lt(cast(planner__core__issuetest__planner_issue.tbl_39.col_239, double UNSIGNED BINARY), 2026), gt(cast(planner__core__issuetest__planner_issue.tbl_39.col_239, double UNSIGNED BINARY), 2011)) + │ └─IndexRangeScan_26 477.36 cop[tikv] table:tbl_39, index:idx_223(col_239) range:(1996,+inf], keep order:true, stats:pseudo + └─TableRowIDScan_28(Probe) 382.00 cop[tikv] table:tbl_39 keep order:false, stats:pseudo +select /*+ use_index_merge( tbl_39) */ col_239 from tbl_39 where not( tbl_39.col_239 not in ( '1994' ) ) and tbl_39.col_239 not in ( '2004' , '2010' , '2010' ) or not( tbl_39.col_239 <= '1996' ) and not( tbl_39.col_239 between '2026' and '2011' ) order by tbl_39.col_239 limit 382; +col_239 +1994 +1997 +drop table if exists t, t1, t2; +create table t (id int,name varchar(10)); +insert into t values(1,'tt'); +create table t1(id int,name varchar(10),name1 varchar(10),name2 varchar(10)); +insert into t1 values(1,'tt','ttt','tttt'),(2,'dd','ddd','dddd'); +create table t2(id int,name varchar(10),name1 varchar(10),name2 varchar(10),`date1` date); +insert into t2 values(1,'tt','ttt','tttt','2099-12-31'),(2,'dd','ddd','dddd','2099-12-31'); +WITH bzzs AS ( +SELECT +count(1) AS bzn +FROM +t c +), +tmp1 AS ( +SELECT +t1.* +FROM +t1 +LEFT JOIN bzzs ON 1 = 1 +WHERE +name IN ('tt') +AND bzn <> 1 +), +tmp2 AS ( +SELECT +tmp1.*, +date('2099-12-31') AS endate +FROM +tmp1 +), +tmp3 AS ( +SELECT +* +FROM +tmp2 +WHERE +endate > CURRENT_DATE +UNION ALL +SELECT +'1' AS id, +'ss' AS name, +'sss' AS name1, +'ssss' AS name2, +date('2099-12-31') AS endate +FROM +bzzs t1 +WHERE +bzn = 1 +) +SELECT +c2.id, +c3.id +FROM +t2 db +LEFT JOIN tmp3 c2 ON c2.id = '1' +LEFT JOIN tmp3 c3 ON c3.id = '1'; +id id +1 1 +1 1 +drop table if exists t; +create table t(a int, b int); +set @@tidb_max_chunk_size = 32; +insert into t values(1, 1); +insert into t select a+1, a+1 from t; +insert into t select a+2, a+2 from t; +insert into t select a+4, a+4 from t; +insert into t select a+8, a+8 from t; +insert into t select a+16, a+16 from t; +insert into t select a+32, a+32 from t; +select a from (select 100 as a, 100 as b union all select * from t) t where b != 0; +a +100 +1 +2 +3 +4 +5 +6 +7 +8 +9 +10 +11 +12 +13 +14 +15 +16 +17 +18 +19 +20 +21 +22 +23 +24 +25 +26 +27 +28 +29 +30 +31 +32 +33 +34 +35 +36 +37 +38 +39 +40 +41 +42 +43 +44 +45 +46 +47 +48 +49 +50 +51 +52 +53 +54 +55 +56 +57 +58 +59 +60 +61 +62 +63 +64 +set @@tidb_max_chunk_size = default; +drop table if exists t1, t2; +create table t1(a varchar(20) collate utf8mb4_bin, index ia(a)); +insert into t1 value('测试'),('测试 '),('xxx '); +explain format = brief select *,length(a) from t1 where a like '测试 %'; +id estRows task access object operator info +Projection 250.00 root planner__core__issuetest__planner_issue.t1.a, length(planner__core__issuetest__planner_issue.t1.a)->Column#3 +└─UnionScan 250.00 root like(planner__core__issuetest__planner_issue.t1.a, "测试 %", 92) + └─IndexReader 250.00 root index:Selection + └─Selection 250.00 cop[tikv] like(planner__core__issuetest__planner_issue.t1.a, "测试 %", 92) + └─IndexRangeScan 250.00 cop[tikv] table:t1, index:ia(a) range:["测试","测试!"), keep order:false, stats:pseudo +explain format = brief select *,length(a) from t1 where a like '测试'; +id estRows task access object operator info +Projection 10.00 root planner__core__issuetest__planner_issue.t1.a, length(planner__core__issuetest__planner_issue.t1.a)->Column#3 +└─UnionScan 10.00 root like(planner__core__issuetest__planner_issue.t1.a, "测试", 92) + └─IndexReader 10.00 root index:Selection + └─Selection 10.00 cop[tikv] like(planner__core__issuetest__planner_issue.t1.a, "测试", 92) + └─IndexRangeScan 10.00 cop[tikv] table:t1, index:ia(a) range:["测试","测试"], keep order:false, stats:pseudo +select *,length(a) from t1 where a like '测试 %'; +a length(a) +测试 8 +select *,length(a) from t1 where a like '测试'; +a length(a) +测试 6 +explain format = brief select * from t1 use index (ia) where a like 'xxx_'; +id estRows task access object operator info +Projection 250.00 root planner__core__issuetest__planner_issue.t1.a +└─UnionScan 250.00 root like(planner__core__issuetest__planner_issue.t1.a, "xxx_", 92) + └─IndexReader 250.00 root index:Selection + └─Selection 250.00 cop[tikv] like(planner__core__issuetest__planner_issue.t1.a, "xxx_", 92) + └─IndexRangeScan 250.00 cop[tikv] table:t1, index:ia(a) range:["xxx","xxy"), keep order:false, stats:pseudo +select * from t1 use index (ia) where a like 'xxx_'; +a +xxx +create table t2(a varchar(20) collate gbk_chinese_ci, index ia(a)); +insert into t2 value('测试'),('测试 '); +explain format = brief select *,length(a) from t2 where a like '测试 %'; +id estRows task access object operator info +Projection 250.00 root planner__core__issuetest__planner_issue.t2.a, length(to_binary(planner__core__issuetest__planner_issue.t2.a))->Column#3 +└─UnionScan 250.00 root like(planner__core__issuetest__planner_issue.t2.a, "测试 %", 92) + └─IndexReader 250.00 root index:Selection + └─Selection 250.00 cop[tikv] like(planner__core__issuetest__planner_issue.t2.a, "测试 %", 92) + └─IndexRangeScan 250.00 cop[tikv] table:t2, index:ia(a) range:["\x89\a\xba%","\x89\a\xba%!"), keep order:false, stats:pseudo +explain format = brief select *,length(a) from t2 where a like '测试'; +id estRows task access object operator info +Projection 10.00 root planner__core__issuetest__planner_issue.t2.a, length(to_binary(planner__core__issuetest__planner_issue.t2.a))->Column#3 +└─UnionScan 10.00 root like(planner__core__issuetest__planner_issue.t2.a, "测试", 92) + └─IndexReader 10.00 root index:Selection + └─Selection 10.00 cop[tikv] like(planner__core__issuetest__planner_issue.t2.a, "测试", 92) + └─IndexRangeScan 10.00 cop[tikv] table:t2, index:ia(a) range:["\x89\a\xba%","\x89\a\xba%"], keep order:false, stats:pseudo +select *,length(a) from t2 where a like '测试 %'; +a length(a) +测试 6 +select *,length(a) from t2 where a like '测试'; +a length(a) +测试 4 +drop view if exists v1; +create view v1(id) as +with recursive cte(a) as (select 1 union select a+1 from cte where a<3) +select * from cte; +create table test2(id int,value int); +insert into test2 values(1,1),(2,2),(3,3),(4,4),(5,5); +update test2 +set value=0 +where test2.id in +( +select * from v1 +); +select * from test2; +id value +1 0 +2 0 +3 0 +4 4 +5 5 +create table A(a int primary key, b int); +create table B(b int primary key); +create table C(c int primary key, b int); +insert into A values (2, 1), (3, 2); +insert into B values (1), (2); +select b.b +from A a +left join ( +B b +left join C c on b.b = c.b) +on b.b = a.b +where a.a in (2, 3); +b +1 +2 +select b.b +from A a +left join ( +B b +left join C c on b.b = c.b) +on b.b = a.b +where a.a in (2, 3, null); +b +1 +2 diff --git a/tests/integrationtest/t/planner/core/issuetest/planner_issue.test b/tests/integrationtest/t/planner/core/issuetest/planner_issue.test new file mode 100644 index 0000000000000..1c461f5616784 --- /dev/null +++ b/tests/integrationtest/t/planner/core/issuetest/planner_issue.test @@ -0,0 +1,214 @@ +# TestIssue43178 +CREATE TABLE aa311c3c ( + 57fd8d09 year(4) DEFAULT '1913', + afbdd7c3 char(220) DEFAULT 'gakkl6occ0yd2jmhi2qxog8szibtcqwxyxmga3hp4ktszjplmg3rjvu8v6lgn9q6hva2lekhw6napjejbut6svsr8q2j8w8rc551e5vq', + 43b06e99 date NOT NULL DEFAULT '3403-10-08', + b80b3746 tinyint(4) NOT NULL DEFAULT '34', + 6302d8ac timestamp DEFAULT '2004-04-01 18:21:18', + PRIMARY KEY (43b06e99,b80b3746) /*T![clustered_index] CLUSTERED */, + KEY 3080c821 (57fd8d09,43b06e99,b80b3746), + KEY a9af33a4 (57fd8d09,b80b3746,43b06e99), + KEY 464b386e (b80b3746), + KEY 19dc3c2d (57fd8d09) + ) ENGINE=InnoDB DEFAULT CHARSET=ascii COLLATE=ascii_bin COMMENT='320f8401'; +explain select /*+ use_index_merge( `aa311c3c` ) */ `aa311c3c`.`43b06e99` as r0 , `aa311c3c`.`6302d8ac` as r1 from `aa311c3c` where IsNull( `aa311c3c`.`b80b3746` ) or not( `aa311c3c`.`57fd8d09` >= '2008' ) order by r0,r1 limit 95; + +# TestIssue43645 +CREATE TABLE t1(id int,col1 varchar(10),col2 varchar(10),col3 varchar(10)); +CREATE TABLE t2(id int,col1 varchar(10),col2 varchar(10),col3 varchar(10)); +INSERT INTO t1 values(1,NULL,NULL,null),(2,NULL,NULL,null),(3,NULL,NULL,null); +INSERT INTO t2 values(1,'a','aa','aaa'),(2,'b','bb','bbb'),(3,'c','cc','ccc'); +WITH tmp AS (SELECT t2.* FROM t2) select (SELECT tmp.col1 FROM tmp WHERE tmp.id=t1.id ) col1, (SELECT tmp.col2 FROM tmp WHERE tmp.id=t1.id ) col2, (SELECT tmp.col3 FROM tmp WHERE tmp.id=t1.id ) col3 from t1; + +# TestIssue29221 +set tidb_enable_index_merge=on; +drop table if exists t; +create table t(a int, b int, index idx_a(a), index idx_b(b)); +set @@session.sql_select_limit=3; +explain format = 'brief' select * from t where a = 1 or b = 1; +explain format = 'brief' select /*+ use_index_merge(t) */ * from t where a = 1 or b = 1; +set @@session.sql_select_limit=18446744073709551615; +explain format = 'brief' select * from t where a = 1 or b = 1; +explain format = 'brief' select * from t where a = 1 or b = 1 limit 3; + +# TestIssue44051 +drop table if exists t1, t2; +CREATE TABLE t1(id int,col1 varchar(10),col2 varchar(10),col3 varchar(10)); +CREATE TABLE t2(id int,col1 varchar(10),col2 varchar(10),col3 varchar(10)); +INSERT INTO t1 values(1,NULL,NULL,null),(2,NULL,NULL,null),(3,NULL,NULL,null); +INSERT INTO t2 values(1,'a','aa','aaa'),(2,'b','bb','bbb'),(3,'c','cc','ccc'); +WITH tmp AS (SELECT t2.* FROM t2) SELECT * FROM t1 WHERE t1.id = (select id from tmp where id = 1) or t1.id = (select id from tmp where id = 2) or t1.id = (select id from tmp where id = 3); + +# TestIssue42732 +drop table if exists t1, t2; +CREATE TABLE t1 (a INT, b INT); +CREATE TABLE t2 (a INT, b INT); +INSERT INTO t1 VALUES (1, 1); +INSERT INTO t2 VALUES (1, 1); +SELECT one.a, one.b as b2 FROM t1 one ORDER BY (SELECT two.b FROM t2 two WHERE two.a = one.b); + +# TestIssue45036 +CREATE TABLE ads_txn ( + `cusno` varchar(10) NOT NULL, + `txn_dt` varchar(8) NOT NULL, + `unn_trno` decimal(22,0) NOT NULL, + `aml_cntpr_accno` varchar(64) DEFAULT NULL, + `acpayr_accno` varchar(35) DEFAULT NULL, + PRIMARY KEY (`cusno`,`txn_dt`,`unn_trno`) NONCLUSTERED +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin +PARTITION BY LIST COLUMNS(`txn_dt`) +(PARTITION `p20000101` VALUES IN ('20000101'), +PARTITION `p20220101` VALUES IN ('20220101'), +PARTITION `p20230516` VALUES IN ('20230516')); +analyze table ads_txn; +set autocommit=OFF; +explain update ads_txn s set aml_cntpr_accno = trim(acpayr_accno) where s._tidb_rowid between 1 and 100000; + +# TestIssue45758 +CREATE TABLE tb1 (cid INT, code INT, class VARCHAR(10)); +CREATE TABLE tb2 (cid INT, code INT, class VARCHAR(10)); +UPDATE tb1, (SELECT code AS cid, code, MAX(class) AS class FROM tb2 GROUP BY code) tb3 SET tb1.cid = tb3.cid, tb1.code = tb3.code, tb1.class = tb3.class; + +# TestIssue46083 +CREATE TEMPORARY TABLE v0(v1 int); +INSERT INTO v0 WITH ta2 AS (TABLE v0) TABLE ta2 FOR UPDATE OF ta2; + +# TestIssue46005 +create table tbl_39(col_239 year(4) not null default '2009', primary key(col_239), unique key idx_223(col_239), key idx_224(col_239)); +insert into tbl_39 values (1994),(1995),(1996),(1997); +explain select /*+ use_index_merge( tbl_39) */ col_239 from tbl_39 where not( tbl_39.col_239 not in ( '1994' ) ) and tbl_39.col_239 not in ( '2004' , '2010' , '2010' ) or not( tbl_39.col_239 <= '1996' ) and not( tbl_39.col_239 between '2026' and '2011' ) order by tbl_39.col_239 limit 382; +select /*+ use_index_merge( tbl_39) */ col_239 from tbl_39 where not( tbl_39.col_239 not in ( '1994' ) ) and tbl_39.col_239 not in ( '2004' , '2010' , '2010' ) or not( tbl_39.col_239 <= '1996' ) and not( tbl_39.col_239 between '2026' and '2011' ) order by tbl_39.col_239 limit 382; + +# https://github.com/pingcap/tidb/issues/47881 +drop table if exists t, t1, t2; +create table t (id int,name varchar(10)); +insert into t values(1,'tt'); +create table t1(id int,name varchar(10),name1 varchar(10),name2 varchar(10)); +insert into t1 values(1,'tt','ttt','tttt'),(2,'dd','ddd','dddd'); +create table t2(id int,name varchar(10),name1 varchar(10),name2 varchar(10),`date1` date); +insert into t2 values(1,'tt','ttt','tttt','2099-12-31'),(2,'dd','ddd','dddd','2099-12-31'); +WITH bzzs AS ( + SELECT + count(1) AS bzn + FROM + t c +), +tmp1 AS ( + SELECT + t1.* + FROM + t1 + LEFT JOIN bzzs ON 1 = 1 + WHERE + name IN ('tt') + AND bzn <> 1 +), +tmp2 AS ( + SELECT + tmp1.*, + date('2099-12-31') AS endate + FROM + tmp1 +), +tmp3 AS ( + SELECT + * + FROM + tmp2 + WHERE + endate > CURRENT_DATE + UNION ALL + SELECT + '1' AS id, + 'ss' AS name, + 'sss' AS name1, + 'ssss' AS name2, + date('2099-12-31') AS endate + FROM + bzzs t1 + WHERE + bzn = 1 +) +SELECT + c2.id, + c3.id +FROM + t2 db + LEFT JOIN tmp3 c2 ON c2.id = '1' + LEFT JOIN tmp3 c3 ON c3.id = '1'; + +# https://github.com/pingcap/tidb/issues/48755 +drop table if exists t; +create table t(a int, b int); +set @@tidb_max_chunk_size = 32; +# insert into more than 32 rows to the table. +insert into t values(1, 1); +insert into t select a+1, a+1 from t; +insert into t select a+2, a+2 from t; +insert into t select a+4, a+4 from t; +insert into t select a+8, a+8 from t; +insert into t select a+16, a+16 from t; +insert into t select a+32, a+32 from t; +select a from (select 100 as a, 100 as b union all select * from t) t where b != 0; +set @@tidb_max_chunk_size = default; + +# https://github.com/pingcap/tidb/issues/48821 +# https://github.com/pingcap/tidb/issues/48983 +drop table if exists t1, t2; +create table t1(a varchar(20) collate utf8mb4_bin, index ia(a)); +insert into t1 value('测试'),('测试 '),('xxx '); +explain format = brief select *,length(a) from t1 where a like '测试 %'; +explain format = brief select *,length(a) from t1 where a like '测试'; +select *,length(a) from t1 where a like '测试 %'; +select *,length(a) from t1 where a like '测试'; +explain format = brief select * from t1 use index (ia) where a like 'xxx_'; +select * from t1 use index (ia) where a like 'xxx_'; +create table t2(a varchar(20) collate gbk_chinese_ci, index ia(a)); +insert into t2 value('测试'),('测试 '); +explain format = brief select *,length(a) from t2 where a like '测试 %'; +explain format = brief select *,length(a) from t2 where a like '测试'; +select *,length(a) from t2 where a like '测试 %'; +select *,length(a) from t2 where a like '测试'; + +# https://github.com/pingcap/tidb/issues/48969 +drop view if exists v1; +create view v1(id) as +with recursive cte(a) as (select 1 union select a+1 from cte where a<3) +select * from cte; + +create table test2(id int,value int); +insert into test2 values(1,1),(2,2),(3,3),(4,4),(5,5); + +update test2 +set value=0 +where test2.id in +( + select * from v1 +); +select * from test2; + +# https://github.com/pingcap/tidb/issues/51560 +create table A(a int primary key, b int); +create table B(b int primary key); +create table C(c int primary key, b int); + +insert into A values (2, 1), (3, 2); +insert into B values (1), (2); + +# Returns data as expected +select b.b +from A a +left join ( + B b + left join C c on b.b = c.b) +on b.b = a.b +where a.a in (2, 3); + +# Returns the same. +select b.b +from A a +left join ( + B b + left join C c on b.b = c.b) +on b.b = a.b +where a.a in (2, 3, null);