diff --git a/cmd/explaintest/r/cte.result b/cmd/explaintest/r/cte.result index b133a248fbd5a..078de63d8658b 100644 --- a/cmd/explaintest/r/cte.result +++ b/cmd/explaintest/r/cte.result @@ -1,3 +1,7 @@ +drop database if exists cte; +create database cte; +drop database if exists cte1; +create database cte1; use test; drop table if exists tbl_0; create table tbl_0(a int); @@ -725,7 +729,7 @@ c1 c2 2 1 2 2 2 3 -use test; +use cte; drop table if exists t1, t2; drop view if exists v1; create table t1 (a int); @@ -733,23 +737,22 @@ insert into t1 values (0), (1), (2), (3), (4); create table t2 (a int); insert into t2 values (1), (2), (3), (4), (5); drop view if exists v1,v2; -create view v1 as with t1 as (select a from t2 where t2.a=3 union select t2.a+1 from t1,t2 where t1.a=t2.a) select * from t1 order by a desc; -create view v2 as with recursive t1 as ( select a from t2 where t2.a=3 union select t2.a+1 from t1,t2 where t1.a=t2.a) select * from t1 order by a desc; -create database if not exists test1; -use test1; -select * from test.v1; +create view v1 as with t1 as (select a from t2 where t2.a=3 union select t2.a+1 from t1,t2 where t1.a=t2.a) select * from t1 order by a desc limit 5; +create view v2 as with recursive t1 as ( select a from t2 where t2.a=3 union select t2.a+1 from t1,t2 where t1.a=t2.a) select * from t1 order by a desc limit 5; +use cte1; +select * from cte.v1; a 5 4 3 2 -select * from test.v2; +select * from cte.v2; a 6 5 4 3 -use test; +use cte; drop table if exists t ,t1, t2; create table t(a int); insert into t values (0); @@ -759,33 +762,33 @@ create table t2 (c int); insert into t2 values (0); drop view if exists v1; create view v1 as with t1 as (with t11 as (select * from t) select * from t1, t2) select * from t1; -use test1; -select * from test.v1; +use cte1; +select * from cte.v1; b c 0 0 -use test; +use cte; drop table if exists t11111; create table t11111 (d int); insert into t11111 values (123), (223), (323); drop view if exists v1; create view v1 as WITH t123 AS (WITH t11111 AS ( SELECT * FROM t1 ) SELECT ( WITH t2 AS ( SELECT ( WITH t23 AS ( SELECT * FROM t11111 ) SELECT * FROM t23 LIMIT 1 ) FROM t11111 ) SELECT * FROM t2 LIMIT 1 ) FROM t11111, t2 ) SELECT * FROM t11111; -use test1; -select * from test.v1; +use cte1; +select * from cte.v1; d 123 223 323 -use test; +use cte; drop table if exists t1; create table t1 (a int); insert into t1 values (1); drop view if exists v1; create view v1 as SELECT (WITH qn AS (SELECT 10*a as a FROM t1),qn2 AS (SELECT 3*a AS b FROM qn) SELECT * from qn2 LIMIT 1) FROM t1; -use test1; -select * from test.v1; +use cte1; +select * from cte.v1; name_exp_1 30 -use test; +use cte; drop table if exists t1,t2; create table t1 (a int); insert into t1 values (0), (1); @@ -793,8 +796,8 @@ create table t2 (b int); insert into t2 values (4), (5); drop view if exists v1; create view v1 as with t1 as (with t11 as (select * from t1) select * from t1, t2) select * from t1; -use test1; -select * from test.v1; +use cte1; +select * from cte.v1; a b 0 5 0 4 @@ -820,3 +823,378 @@ INSERT INTO `t_dnmxh` VALUES (104,571000,NULL),(104,572000,44.37),(104,573000,59 WITH cte_0 AS (select distinct ref_0.wkey as c0, ref_0.pkey as c1, ref_0.c_xhsndb as c2 from t_dnmxh as ref_0 where (1 <= ( select ref_1.pkey not in ( select ref_5.wkey as c0 from t_dnmxh as ref_5 where (ref_5.wkey < ( select ref_6.pkey as c0 from t_cqmg3b as ref_6 where 88 between 96 and 76)) ) as c0 from (t_cqmg3b as ref_1 left outer join t_dnmxh as ref_2 on (ref_1.wkey = ref_2.wkey )) where ref_0.c_xhsndb is NULL union select 33 <= 91 as c0 from t_cqmg3b as ref_8 ))), cte_1 AS (select ref_9.wkey as c0, ref_9.pkey as c1, ref_9.c_anpf_c as c2, ref_9.c_b_fp_c as c3, ref_9.c_ndccfb as c4, ref_9.c_8rswc as c5 from t_cqmg3b as ref_9) select count(1) from cte_0 as ref_10 where case when 56 < 50 then case when 100 in ( select distinct ref_11.c4 as c0 from cte_1 as ref_11 where (ref_11.c4 > ( select ref_13.pkey as c0 from t_dnmxh as ref_13 where (ref_13.wkey > ( select distinct ref_11.c1 as c0 from cte_0 as ref_14)) )) or (1 = 1)) then null else null end else '7mxv6' end not like 'ki4%vc'; count(1) 24 +with cte1 as (select 1), cte2 as (select 2) select * from cte1 union (with cte2 as (select 3) select * from cte2 union all select * from cte2) order by 1; +1 +1 +2 +drop table if exists tt, tt1, tt2, tt3, tt4, tt5; +create table tt(c1 int, c2 int); +create table tt1(c1 int, c2 int); +create table tt2(c1 int, c2 int); +create table tt3(c1 int, c2 int); +create table tt4(c1 int, c2 int); +create table tt5(c1 int, c2 int); +insert into tt values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +insert into tt1 values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +insert into tt2 values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +insert into tt3 values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +insert into tt4 values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +insert into tt5 values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +explain with recursive cte1 as (select c1 from tt union select c1 from cte1 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte1.c1)) select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) order by 1; +id estRows task access object operator info +Sort_33 7992.00 root cte1.tt2.c1 +└─HashJoin_36 7992.00 root semi join, equal:[eq(cte1.tt2.c1, cte1.tt.c1)] + ├─Selection_40(Build) 6400.00 root not(isnull(cte1.tt.c1)) + │ └─CTEFullScan_41 8000.00 root CTE:cte1 data:CTE_0 + └─TableReader_39(Probe) 9990.00 root data:Selection_38 + └─Selection_38 9990.00 cop[tikv] not(isnull(cte1.tt2.c1)) + └─TableFullScan_37 10000.00 cop[tikv] table:tt2 keep order:false, stats:pseudo +CTE_0 8000.00 root Recursive CTE +├─TableReader_24(Seed Part) 10000.00 root data:TableFullScan_23 +│ └─TableFullScan_23 10000.00 cop[tikv] table:tt keep order:false, stats:pseudo +└─HashJoin_27(Recursive Part) 6400.00 root semi join, equal:[eq(cte1.tt.c1, cte1.tt1.c2)] + ├─TableReader_32(Build) 9990.00 root data:Selection_31 + │ └─Selection_31 9990.00 cop[tikv] not(isnull(cte1.tt1.c2)) + │ └─TableFullScan_30 10000.00 cop[tikv] table:tt1 keep order:false, stats:pseudo + └─Selection_28(Probe) 8000.00 root not(isnull(cte1.tt.c1)) + └─CTETable_29 10000.00 root Scan on CTE_0 +with recursive cte1 as (select c1 from tt union select c1 from cte1 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte1.c1)) select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) order by 1; +c1 +1 +2 +3 +4 +5 +6 +explain with recursive cte1 as (select c1 from tt union select c1 from cte1 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte1.c1)) +select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) union select c1 from tt3 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt3.c1) union +select c1 from tt4 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt4.c1) union select c1 from tt5 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt5.c1) order by 1; +id estRows task access object operator info +Sort_63 25574.40 root Column#28 +└─HashAgg_65 25574.40 root group by:Column#28, funcs:firstrow(Column#28)->Column#28 + └─Union_66 31968.00 root + ├─HashJoin_68 7992.00 root semi join, equal:[eq(cte1.tt2.c1, cte1.tt.c1)] + │ ├─Selection_72(Build) 6400.00 root not(isnull(cte1.tt.c1)) + │ │ └─CTEFullScan_73 8000.00 root CTE:cte1 data:CTE_0 + │ └─TableReader_71(Probe) 9990.00 root data:Selection_70 + │ └─Selection_70 9990.00 cop[tikv] not(isnull(cte1.tt2.c1)) + │ └─TableFullScan_69 10000.00 cop[tikv] table:tt2 keep order:false, stats:pseudo + ├─HashJoin_75 7992.00 root semi join, equal:[eq(cte1.tt3.c1, cte1.tt.c1)] + │ ├─Selection_79(Build) 6400.00 root not(isnull(cte1.tt.c1)) + │ │ └─CTEFullScan_80 8000.00 root CTE:cte1 data:CTE_0 + │ └─TableReader_78(Probe) 9990.00 root data:Selection_77 + │ └─Selection_77 9990.00 cop[tikv] not(isnull(cte1.tt3.c1)) + │ └─TableFullScan_76 10000.00 cop[tikv] table:tt3 keep order:false, stats:pseudo + ├─HashJoin_82 7992.00 root semi join, equal:[eq(cte1.tt4.c1, cte1.tt.c1)] + │ ├─Selection_86(Build) 6400.00 root not(isnull(cte1.tt.c1)) + │ │ └─CTEFullScan_87 8000.00 root CTE:cte1 data:CTE_0 + │ └─TableReader_85(Probe) 9990.00 root data:Selection_84 + │ └─Selection_84 9990.00 cop[tikv] not(isnull(cte1.tt4.c1)) + │ └─TableFullScan_83 10000.00 cop[tikv] table:tt4 keep order:false, stats:pseudo + └─HashJoin_89 7992.00 root semi join, equal:[eq(cte1.tt5.c1, cte1.tt.c1)] + ├─Selection_93(Build) 6400.00 root not(isnull(cte1.tt.c1)) + │ └─CTEFullScan_94 8000.00 root CTE:cte1 data:CTE_0 + └─TableReader_92(Probe) 9990.00 root data:Selection_91 + └─Selection_91 9990.00 cop[tikv] not(isnull(cte1.tt5.c1)) + └─TableFullScan_90 10000.00 cop[tikv] table:tt5 keep order:false, stats:pseudo +CTE_0 8000.00 root Recursive CTE +├─TableReader_54(Seed Part) 10000.00 root data:TableFullScan_53 +│ └─TableFullScan_53 10000.00 cop[tikv] table:tt keep order:false, stats:pseudo +└─HashJoin_57(Recursive Part) 6400.00 root semi join, equal:[eq(cte1.tt.c1, cte1.tt1.c2)] + ├─TableReader_62(Build) 9990.00 root data:Selection_61 + │ └─Selection_61 9990.00 cop[tikv] not(isnull(cte1.tt1.c2)) + │ └─TableFullScan_60 10000.00 cop[tikv] table:tt1 keep order:false, stats:pseudo + └─Selection_58(Probe) 8000.00 root not(isnull(cte1.tt.c1)) + └─CTETable_59 10000.00 root Scan on CTE_0 +with recursive cte1 as (select c1 from tt union select c1 from cte1 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte1.c1)) +select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) union select c1 from tt3 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt3.c1) union +select c1 from tt4 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt4.c1) union select c1 from tt5 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt5.c1) order by 1; +c1 +1 +2 +3 +4 +5 +6 +explain with cte1 as (with recursive cte2 as (select c1 from tt union all select c1 from cte2 where exists(select /*+ no_decorrelate() */ c1 from tt1 where tt1.c1 = cte2.c1) limit 300) +select c1 from tt union select c1 from cte2 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte2.c1)) +select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) union select c1 from tt3 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt3.c1) union +select c1 from tt4 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt4.c1) union select c1 from tt5 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt5.c1) order by 1; +id estRows task access object operator info +Sort_92 25574.40 root Column#36 +└─HashAgg_94 25574.40 root group by:Column#36, funcs:firstrow(Column#36)->Column#36 + └─Union_95 31968.00 root + ├─HashJoin_97 7992.00 root semi join, equal:[eq(cte1.tt2.c1, Column#23)] + │ ├─Selection_101(Build) 10489.60 root not(isnull(Column#23)) + │ │ └─CTEFullScan_102 13112.00 root CTE:cte1 data:CTE_0 + │ └─TableReader_100(Probe) 9990.00 root data:Selection_99 + │ └─Selection_99 9990.00 cop[tikv] not(isnull(cte1.tt2.c1)) + │ └─TableFullScan_98 10000.00 cop[tikv] table:tt2 keep order:false, stats:pseudo + ├─HashJoin_104 7992.00 root semi join, equal:[eq(cte1.tt3.c1, Column#27)] + │ ├─Selection_108(Build) 10489.60 root not(isnull(Column#27)) + │ │ └─CTEFullScan_109 13112.00 root CTE:cte1 data:CTE_0 + │ └─TableReader_107(Probe) 9990.00 root data:Selection_106 + │ └─Selection_106 9990.00 cop[tikv] not(isnull(cte1.tt3.c1)) + │ └─TableFullScan_105 10000.00 cop[tikv] table:tt3 keep order:false, stats:pseudo + ├─HashJoin_111 7992.00 root semi join, equal:[eq(cte1.tt4.c1, Column#31)] + │ ├─Selection_115(Build) 10489.60 root not(isnull(Column#31)) + │ │ └─CTEFullScan_116 13112.00 root CTE:cte1 data:CTE_0 + │ └─TableReader_114(Probe) 9990.00 root data:Selection_113 + │ └─Selection_113 9990.00 cop[tikv] not(isnull(cte1.tt4.c1)) + │ └─TableFullScan_112 10000.00 cop[tikv] table:tt4 keep order:false, stats:pseudo + └─HashJoin_118 7992.00 root semi join, equal:[eq(cte1.tt5.c1, Column#35)] + ├─Selection_122(Build) 10489.60 root not(isnull(Column#35)) + │ └─CTEFullScan_123 13112.00 root CTE:cte1 data:CTE_0 + └─TableReader_121(Probe) 9990.00 root data:Selection_120 + └─Selection_120 9990.00 cop[tikv] not(isnull(cte1.tt5.c1)) + └─TableFullScan_119 10000.00 cop[tikv] table:tt5 keep order:false, stats:pseudo +CTE_0 13112.00 root Non-Recursive CTE +└─HashAgg_79(Seed Part) 13112.00 root group by:Column#19, funcs:firstrow(Column#19)->Column#19 + └─Union_80 20486.00 root + ├─TableReader_84 9990.00 root data:Selection_83 + │ └─Selection_83 9990.00 cop[tikv] or(or(not(isnull(cte1.tt.c1)), not(isnull(cte1.tt.c1))), or(not(isnull(cte1.tt.c1)), not(isnull(cte1.tt.c1)))) + │ └─TableFullScan_82 10000.00 cop[tikv] table:tt keep order:false, stats:pseudo + └─HashJoin_86 10496.00 root semi join, equal:[eq(cte1.tt.c1, cte1.tt1.c2)] + ├─TableReader_91(Build) 9990.00 root data:Selection_90 + │ └─Selection_90 9990.00 cop[tikv] not(isnull(cte1.tt1.c2)) + │ └─TableFullScan_89 10000.00 cop[tikv] table:tt1 keep order:false, stats:pseudo + └─Selection_87(Probe) 13120.00 root not(isnull(cte1.tt.c1)) + └─CTEFullScan_88 16400.00 root CTE:cte2 data:CTE_1 +CTE_1 16400.00 root Recursive CTE, limit(offset:0, count:300) +├─TableReader_70(Seed Part) 10000.00 root data:TableFullScan_69 +│ └─TableFullScan_69 10000.00 cop[tikv] table:tt keep order:false, stats:pseudo +└─HashJoin_73(Recursive Part) 6400.00 root semi join, equal:[eq(cte1.tt.c1, cte1.tt1.c1)] + ├─TableReader_78(Build) 9990.00 root data:Selection_77 + │ └─Selection_77 9990.00 cop[tikv] not(isnull(cte1.tt1.c1)) + │ └─TableFullScan_76 10000.00 cop[tikv] table:tt1 keep order:false, stats:pseudo + └─Selection_74(Probe) 8000.00 root not(isnull(cte1.tt.c1)) + └─CTETable_75 10000.00 root Scan on CTE_1 +with cte1 as (with recursive cte2 as (select c1 from tt union all select c1 from cte2 where exists(select /*+ no_decorrelate() */ c1 from tt1 where tt1.c1 = cte2.c1) limit 300) +select c1 from tt union select c1 from cte2 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte2.c1)) +select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) union select c1 from tt3 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt3.c1) union +select c1 from tt4 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt4.c1) union select c1 from tt5 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt5.c1) order by 1; +c1 +1 +2 +3 +4 +5 +6 +drop table if exists table_a, table_b, table_c, table_d, table_e; +CREATE TABLE `table_a` ( +`col_1` varchar(40) DEFAULT NULL, +`col_2` varchar(40) DEFAULT NULL, +`col_3` varchar(500) DEFAULT NULL, +`col_4` varchar(500) DEFAULT NULL, +`col_5` varchar(500) DEFAULT NULL, +`col_6` varchar(500) DEFAULT NULL, +`col_7` decimal(38,6) DEFAULT NULL, +`col_8` decimal(38,6) DEFAULT NULL, +`col_9` decimal(38,6) DEFAULT NULL, +`col_10` decimal(38,6) DEFAULT NULL, +`col_11` decimal(38,6) DEFAULT NULL, +`col_12` decimal(38,6) DEFAULT NULL, +`col_13` decimal(38,6) DEFAULT NULL, +`col_14` decimal(38,6) DEFAULT NULL, +`col_15` decimal(38,6) DEFAULT NULL, +`col_16` decimal(38,6) DEFAULT NULL, +`col_17` decimal(38,6) DEFAULT NULL, +`col_18` decimal(38,6) DEFAULT NULL, +`col_19` varchar(40) DEFAULT NULL, +`col_20` varchar(100) DEFAULT NULL, +`col_21` varchar(100) DEFAULT NULL, +`created_at` timestamp DEFAULT CURRENT_TIMESTAMP, +KEY `index_col_1` (`col_1`), +KEY `index_col_2_3` (`col_2`,`col_3`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; +CREATE TABLE `table_b` ( +`col_1` varchar(8) NOT NULL, +`col_2` varchar(100) NOT NULL, +`col_3` varchar(200) DEFAULT NULL, +`col_4` varchar(10) NOT NULL, +`col_5` decimal(38,6) DEFAULT NULL, +`col_6` decimal(38,6) DEFAULT NULL, +`col_7` decimal(38,6) DEFAULT NULL, +`col_8` decimal(38,6) DEFAULT NULL, +`created_at` datetime DEFAULT CURRENT_TIMESTAMP, +KEY `index_col_1_2` (`col_1`,`col_2`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; +CREATE TABLE `table_c` ( +`col_1` varchar(50) DEFAULT NULL, +`col_2` varchar(50) DEFAULT NULL, +`col_3` varchar(30) DEFAULT NULL, +`col_4` varchar(100) DEFAULT NULL, +`col_5` varchar(50) DEFAULT NULL, +`col_6` varchar(100) DEFAULT NULL, +`col_7` decimal(38,6) DEFAULT NULL, +`col_8` decimal(38,6) DEFAULT NULL, +`col_9` decimal(38,6) DEFAULT NULL, +`col_10` decimal(38,6) DEFAULT NULL, +`col_11` decimal(38,6) DEFAULT NULL, +`col_12` decimal(38,6) DEFAULT NULL, +`col_13` decimal(38,6) DEFAULT NULL, +`col_14` decimal(38,6) DEFAULT NULL, +`col_15` decimal(38,6) DEFAULT NULL, +`col_16` decimal(38,6) DEFAULT NULL, +`col_17` varchar(50) DEFAULT NULL, +`col_18` varchar(50) DEFAULT NULL, +`col_19` varchar(50) DEFAULT NULL, +`created_at` timestamp DEFAULT CURRENT_TIMESTAMP, +KEY `index_col_1_3` (`col_1`,`col_3`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; +CREATE TABLE `table_d` ( +`col_1` decimal(10,0) DEFAULT NULL, +`col_2` varchar(1) DEFAULT NULL, +`col_3` date NOT NULL, +`col_4` varchar(13) DEFAULT NULL, +`col_5` varchar(6) DEFAULT NULL, +`col_6` varchar(255) DEFAULT NULL, +`col_7` decimal(10,0) DEFAULT NULL, +`col_8` varchar(12) DEFAULT NULL, +`col_9` decimal(10,0) DEFAULT NULL, +`col_10` varchar(17) DEFAULT NULL, +`col_11` decimal(10,0) DEFAULT NULL, +`col_12` varchar(7) DEFAULT NULL, +`col_13` date DEFAULT NULL, +`col_14` date DEFAULT NULL, +`col_15` date DEFAULT NULL, +`col_16` date DEFAULT NULL, +`col_17` date DEFAULT NULL, +`col_18` date DEFAULT NULL, +`col_19` date DEFAULT NULL, +`col_20` varchar(1) DEFAULT NULL, +`col_21` varchar(1) DEFAULT NULL, +`col_22` decimal(1,0) DEFAULT NULL, +`col_23` varchar(1) DEFAULT NULL +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; +CREATE TABLE `table_e` ( +`col_1` varchar(8) NOT NULL, +`col_2` varchar(100) NOT NULL, +`col_3` varchar(100) DEFAULT NULL, +`col_4` varchar(100) NOT NULL, +`col_5` varchar(100) DEFAULT NULL, +`col_6` varchar(100) DEFAULT NULL, +`col_7` decimal(38,12) DEFAULT NULL, +`col_8` varchar(100) DEFAULT NULL, +`col_9` varchar(100) DEFAULT NULL, +`col_10` varchar(100) DEFAULT NULL, +`col_11` varchar(100) DEFAULT NULL, +`col_12` varchar(8) DEFAULT NULL, +`col_13` decimal(38,12) DEFAULT NULL, +`col_14` varchar(100) DEFAULT NULL, +`created_at` timestamp DEFAULT CURRENT_TIMESTAMP, +`col_15` varchar(500) DEFAULT NULL, +PRIMARY KEY (`col_2`, `col_1`, `col_4`), +KEY `index_col_5_6` (`col_5`, `col_6`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; +INSERT INTO `table_a` +(`col_1`, `col_2`, `col_3`, `col_4`, `col_5`, `col_6`, `col_7`, +`col_8`, `col_9`, `col_10`, `col_11`, `col_12`, `col_13`, +`col_14`, `col_15`, `col_16`, `col_17`, `col_18`, `col_19`, +`col_20`, `col_21`, `created_at`) +VALUES +('20230628', '20230628', 'Portfolio A', 'Product B', 'Direct', 'USD', +200000, 150000, 50000, 100000, +50000, 10000, 5000, 1.2, 0.1, +0.15, 0.08, 0.02, '2023-06-28', +'2023-06-28', '2025-06-28', CURRENT_TIMESTAMP); +INSERT INTO `table_b` +(`col_1`, `col_2`, `col_3`, `col_4`, `col_5`, `col_6`, `col_7`, `col_8`, `created_at`) +VALUES +('20240628', 'DR201800093', 'Product A', '申购', 1000, 100000, 95000, 1.1, CURRENT_TIMESTAMP); +INSERT INTO `table_c` +(`col_1`, `col_2`, `col_3`, `col_4`, `col_5`, `col_6`, `col_7`, +`col_8`, `col_9`, `col_10`, `col_11`, `col_12`, `col_13`, +`col_14`, `col_15`, `col_16`, `col_17`, `col_18`, `col_19`, `created_at`) +VALUES +('20230628', 'Dept A', 'DR201800093', 'Product A', '孵化', 'Strategy 1', +100000, 100000, 120000, 100, 1.2, +0.2, 0.15, 0.1, 0.05, 0.08, +'2023-06-28', '2025-06-28', '2Y', CURRENT_TIMESTAMP); +INSERT INTO `table_d` +(`col_1`, `col_2`, `col_3`, `col_4`, `col_5`, `col_6`, `col_7`, +`col_8`, `col_9`, `col_10`, `col_11`, `col_12`, `col_13`, `col_14`, +`col_15`, `col_16`, `col_17`, `col_18`, `col_19`, `col_20`, `col_21`, +`col_22`, `col_23`) +VALUES +('20240628', '1', '2024-06-28', 'Friday', '28', 'End of Month', 202406, +'June', 20242, 'Q2', 2024, '2024', '2024-06-27', '2024-05-28', +'2024-03-28', '2023-06-28', '2024-06-27', '2024-06-27', '2024-06-27', +'1', '1', '1', '1'); +INSERT INTO `table_e` +(`col_1`, `col_2`, `col_3`, `col_4`, `col_5`, `col_6`, `col_7`, +`col_8`, `col_9`, `col_10`, `col_11`, `col_12`, `col_13`, `col_14`, +`created_at`, `col_15`) +VALUES +('20230628', 'CFETS_MID', 'Mid', 'USD/CNY', 'USD', 'CNY', +7.0, 'Source A', 'Unit A', 'Region A', '2023-06-28 15:00:00', '20230627', +6.9, 'user_001', CURRENT_TIMESTAMP, 'Exchange rate on 2023-06-28'); +WITH date_table AS ( +SELECT +d.col_1 AS date, +(SELECT MAX(col_1) +FROM table_c a +WHERE col_1 <= +CONCAT(YEAR(DATE_SUB(d.col_1, INTERVAL 1 YEAR)), +'1231') +AND EXISTS (SELECT 1 +FROM table_d d +WHERE a.col_1 = d.col_1 +AND d.col_2 = 1)) AS date1, +(SELECT MAX(col_1) +FROM table_a a +WHERE col_1 <= CONCAT(YEAR(DATE_SUB(d.col_1, INTERVAL 1 YEAR)), +'1231') +AND EXISTS (SELECT 1 +FROM table_d d +WHERE a.col_1 = d.col_1 +AND d.col_2 = 1)) AS date2, +(SELECT MAX(col_1) +FROM table_c +WHERE col_1 <= d.col_1) AS date3, +(SELECT MAX(col_1) +FROM table_a +WHERE col_1 <= d.col_1) AS date4 +FROM table_d d +WHERE d.col_1 = '20240628' +), +rm_am_champs_ex_risk_portfolio_seed_money_1 AS ( +SELECT b.col_2 +FROM table_a b +LEFT JOIN table_e rb +ON rb.col_1 = b.col_19 +AND b.col_6 = rb.col_3 +WHERE b.col_2 = (SELECT date4 FROM date_table) +), +rm_am_champs_ex_risk_portfolio_seed_money_2 AS ( +SELECT b.col_2 +FROM table_a b +LEFT JOIN table_e rb +ON rb.col_1 = b.col_19 +AND b.col_6 = rb.col_3 +), +product_base AS ( +SELECT DISTINCT t.col_3, col_4, 'ML' AS is_do +FROM table_c t +), +product_detail AS ( +SELECT t.col_4, +"3集合" AS nature_investment +FROM product_base t +LEFT JOIN date_table dt +ON 1 = 1 +LEFT JOIN table_c a +ON t.col_4 = a.col_4 +AND a.col_1 = dt.date3 +) +SELECT col_4 +FROM ( +SELECT col_4 +FROM product_detail +UNION ALL +SELECT col_4 +FROM product_detail +) a; +col_4 +Product A +Product A diff --git a/cmd/explaintest/t/cte.test b/cmd/explaintest/t/cte.test index 13edac8f6002e..234c874eefb79 100644 --- a/cmd/explaintest/t/cte.test +++ b/cmd/explaintest/t/cte.test @@ -1,3 +1,7 @@ +drop database if exists cte; +create database cte; +drop database if exists cte1; +create database cte1; use test; # case 1 drop table if exists tbl_0; @@ -258,7 +262,7 @@ explain select * from t1 where exists(with recursive cte1 as (select c1, c2 from select * from t1 where exists(with recursive cte1 as (select c1, c2 from t2 union all select c1+1 as c1, c2+1 as c2 from cte1 where cte1.c2=t1.c2) select c1 from cte1); # Some cases to Test Create View With CTE and checkout Database # With name is the same as the table name -use test; +use cte; drop table if exists t1, t2; drop view if exists v1; create table t1 (a int); @@ -266,14 +270,13 @@ insert into t1 values (0), (1), (2), (3), (4); create table t2 (a int); insert into t2 values (1), (2), (3), (4), (5); drop view if exists v1,v2; -create view v1 as with t1 as (select a from t2 where t2.a=3 union select t2.a+1 from t1,t2 where t1.a=t2.a) select * from t1 order by a desc; -create view v2 as with recursive t1 as ( select a from t2 where t2.a=3 union select t2.a+1 from t1,t2 where t1.a=t2.a) select * from t1 order by a desc; -create database if not exists test1; -use test1; -select * from test.v1; -select * from test.v2; +create view v1 as with t1 as (select a from t2 where t2.a=3 union select t2.a+1 from t1,t2 where t1.a=t2.a) select * from t1 order by a desc limit 5; +create view v2 as with recursive t1 as ( select a from t2 where t2.a=3 union select t2.a+1 from t1,t2 where t1.a=t2.a) select * from t1 order by a desc limit 5; +use cte1; +select * from cte.v1; +select * from cte.v2; # case -use test; +use cte; drop table if exists t ,t1, t2; create table t(a int); insert into t values (0); @@ -283,28 +286,28 @@ create table t2 (c int); insert into t2 values (0); drop view if exists v1; create view v1 as with t1 as (with t11 as (select * from t) select * from t1, t2) select * from t1; -use test1; -select * from test.v1; +use cte1; +select * from cte.v1; # case -use test; +use cte; drop table if exists t11111; create table t11111 (d int); insert into t11111 values (123), (223), (323); drop view if exists v1; create view v1 as WITH t123 AS (WITH t11111 AS ( SELECT * FROM t1 ) SELECT ( WITH t2 AS ( SELECT ( WITH t23 AS ( SELECT * FROM t11111 ) SELECT * FROM t23 LIMIT 1 ) FROM t11111 ) SELECT * FROM t2 LIMIT 1 ) FROM t11111, t2 ) SELECT * FROM t11111; -use test1; -select * from test.v1; +use cte1; +select * from cte.v1; # case -use test; +use cte; drop table if exists t1; create table t1 (a int); insert into t1 values (1); drop view if exists v1; create view v1 as SELECT (WITH qn AS (SELECT 10*a as a FROM t1),qn2 AS (SELECT 3*a AS b FROM qn) SELECT * from qn2 LIMIT 1) FROM t1; -use test1; -select * from test.v1; +use cte1; +select * from cte.v1; # case -use test; +use cte; drop table if exists t1,t2; create table t1 (a int); insert into t1 values (0), (1); @@ -312,8 +315,8 @@ create table t2 (b int); insert into t2 values (4), (5); drop view if exists v1; create view v1 as with t1 as (with t11 as (select * from t1) select * from t1, t2) select * from t1; -use test1; -select * from test.v1; +use cte1; +select * from cte.v1; # case CREATE TABLE `t_cqmg3b` ( `wkey` int(11) DEFAULT NULL, @@ -333,3 +336,278 @@ CREATE TABLE `t_dnmxh` ( ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; INSERT INTO `t_dnmxh` VALUES (104,571000,NULL),(104,572000,44.37),(104,573000,59.91),(104,574000,91.5),(104,575000,9.53),(104,576000,92.4),(104,577000,47.96),(106,585000,NULL),(106,586000,NULL),(106,587000,NULL),(106,588000,NULL),(106,589000,NULL),(108,595000,13.35),(108,596000,13.51),(108,597000,47.51),(108,598000,NULL),(113,616000,24.73),(113,617000,NULL),(113,618000,92.6),(113,619000,NULL),(113,620000,91.65),(113,621000,100.46),(113,622000,31.3),(113,623000,63.81); WITH cte_0 AS (select distinct ref_0.wkey as c0, ref_0.pkey as c1, ref_0.c_xhsndb as c2 from t_dnmxh as ref_0 where (1 <= ( select ref_1.pkey not in ( select ref_5.wkey as c0 from t_dnmxh as ref_5 where (ref_5.wkey < ( select ref_6.pkey as c0 from t_cqmg3b as ref_6 where 88 between 96 and 76)) ) as c0 from (t_cqmg3b as ref_1 left outer join t_dnmxh as ref_2 on (ref_1.wkey = ref_2.wkey )) where ref_0.c_xhsndb is NULL union select 33 <= 91 as c0 from t_cqmg3b as ref_8 ))), cte_1 AS (select ref_9.wkey as c0, ref_9.pkey as c1, ref_9.c_anpf_c as c2, ref_9.c_b_fp_c as c3, ref_9.c_ndccfb as c4, ref_9.c_8rswc as c5 from t_cqmg3b as ref_9) select count(1) from cte_0 as ref_10 where case when 56 < 50 then case when 100 in ( select distinct ref_11.c4 as c0 from cte_1 as ref_11 where (ref_11.c4 > ( select ref_13.pkey as c0 from t_dnmxh as ref_13 where (ref_13.wkey > ( select distinct ref_11.c1 as c0 from cte_0 as ref_14)) )) or (1 = 1)) then null else null end else '7mxv6' end not like 'ki4%vc'; +#case +with cte1 as (select 1), cte2 as (select 2) select * from cte1 union (with cte2 as (select 3) select * from cte2 union all select * from cte2) order by 1; + +# case: test CTE with complicated Apply and other operators +drop table if exists tt, tt1, tt2, tt3, tt4, tt5; +create table tt(c1 int, c2 int); +create table tt1(c1 int, c2 int); +create table tt2(c1 int, c2 int); +create table tt3(c1 int, c2 int); +create table tt4(c1 int, c2 int); +create table tt5(c1 int, c2 int); +insert into tt values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +insert into tt1 values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +insert into tt2 values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +insert into tt3 values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +insert into tt4 values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); +insert into tt5 values(1, 1), (2, 2), (3, 3), (4, 4), (5, 5), (6, 6); + +## sub case-1: CTE with Apply +explain with recursive cte1 as (select c1 from tt union select c1 from cte1 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte1.c1)) select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) order by 1; + +with recursive cte1 as (select c1 from tt union select c1 from cte1 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte1.c1)) select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) order by 1; + +## sub case-2: CTE with Apply and Union +explain with recursive cte1 as (select c1 from tt union select c1 from cte1 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte1.c1)) +select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) union select c1 from tt3 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt3.c1) union +select c1 from tt4 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt4.c1) union select c1 from tt5 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt5.c1) order by 1; + +with recursive cte1 as (select c1 from tt union select c1 from cte1 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte1.c1)) +select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) union select c1 from tt3 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt3.c1) union +select c1 from tt4 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt4.c1) union select c1 from tt5 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt5.c1) order by 1; + +## sub case-3: nested CTE with Apply and union +explain with cte1 as (with recursive cte2 as (select c1 from tt union all select c1 from cte2 where exists(select /*+ no_decorrelate() */ c1 from tt1 where tt1.c1 = cte2.c1) limit 300) +select c1 from tt union select c1 from cte2 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte2.c1)) +select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) union select c1 from tt3 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt3.c1) union +select c1 from tt4 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt4.c1) union select c1 from tt5 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt5.c1) order by 1; + +with cte1 as (with recursive cte2 as (select c1 from tt union all select c1 from cte2 where exists(select /*+ no_decorrelate() */ c1 from tt1 where tt1.c1 = cte2.c1) limit 300) +select c1 from tt union select c1 from cte2 where exists (select /*+ no_decorrelate() */ c1 from tt1 where tt1.c2 = cte2.c1)) +select c1 from tt2 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt2.c1) union select c1 from tt3 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt3.c1) union +select c1 from tt4 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt4.c1) union select c1 from tt5 where exists (select /*+ no_decorrelate() */ * from cte1 where cte1.c1 = tt5.c1) order by 1; + +## sub case-4: simplified user query +drop table if exists table_a, table_b, table_c, table_d, table_e; +CREATE TABLE `table_a` ( + `col_1` varchar(40) DEFAULT NULL, + `col_2` varchar(40) DEFAULT NULL, + `col_3` varchar(500) DEFAULT NULL, + `col_4` varchar(500) DEFAULT NULL, + `col_5` varchar(500) DEFAULT NULL, + `col_6` varchar(500) DEFAULT NULL, + `col_7` decimal(38,6) DEFAULT NULL, + `col_8` decimal(38,6) DEFAULT NULL, + `col_9` decimal(38,6) DEFAULT NULL, + `col_10` decimal(38,6) DEFAULT NULL, + `col_11` decimal(38,6) DEFAULT NULL, + `col_12` decimal(38,6) DEFAULT NULL, + `col_13` decimal(38,6) DEFAULT NULL, + `col_14` decimal(38,6) DEFAULT NULL, + `col_15` decimal(38,6) DEFAULT NULL, + `col_16` decimal(38,6) DEFAULT NULL, + `col_17` decimal(38,6) DEFAULT NULL, + `col_18` decimal(38,6) DEFAULT NULL, + `col_19` varchar(40) DEFAULT NULL, + `col_20` varchar(100) DEFAULT NULL, + `col_21` varchar(100) DEFAULT NULL, + `created_at` timestamp DEFAULT CURRENT_TIMESTAMP, + KEY `index_col_1` (`col_1`), + KEY `index_col_2_3` (`col_2`,`col_3`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; + + +CREATE TABLE `table_b` ( + `col_1` varchar(8) NOT NULL, + `col_2` varchar(100) NOT NULL, + `col_3` varchar(200) DEFAULT NULL, + `col_4` varchar(10) NOT NULL, + `col_5` decimal(38,6) DEFAULT NULL, + `col_6` decimal(38,6) DEFAULT NULL, + `col_7` decimal(38,6) DEFAULT NULL, + `col_8` decimal(38,6) DEFAULT NULL, + `created_at` datetime DEFAULT CURRENT_TIMESTAMP, + KEY `index_col_1_2` (`col_1`,`col_2`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; + +CREATE TABLE `table_c` ( + `col_1` varchar(50) DEFAULT NULL, + `col_2` varchar(50) DEFAULT NULL, + `col_3` varchar(30) DEFAULT NULL, + `col_4` varchar(100) DEFAULT NULL, + `col_5` varchar(50) DEFAULT NULL, + `col_6` varchar(100) DEFAULT NULL, + `col_7` decimal(38,6) DEFAULT NULL, + `col_8` decimal(38,6) DEFAULT NULL, + `col_9` decimal(38,6) DEFAULT NULL, + `col_10` decimal(38,6) DEFAULT NULL, + `col_11` decimal(38,6) DEFAULT NULL, + `col_12` decimal(38,6) DEFAULT NULL, + `col_13` decimal(38,6) DEFAULT NULL, + `col_14` decimal(38,6) DEFAULT NULL, + `col_15` decimal(38,6) DEFAULT NULL, + `col_16` decimal(38,6) DEFAULT NULL, + `col_17` varchar(50) DEFAULT NULL, + `col_18` varchar(50) DEFAULT NULL, + `col_19` varchar(50) DEFAULT NULL, + `created_at` timestamp DEFAULT CURRENT_TIMESTAMP, + KEY `index_col_1_3` (`col_1`,`col_3`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; + +CREATE TABLE `table_d` ( + `col_1` decimal(10,0) DEFAULT NULL, + `col_2` varchar(1) DEFAULT NULL, + `col_3` date NOT NULL, + `col_4` varchar(13) DEFAULT NULL, + `col_5` varchar(6) DEFAULT NULL, + `col_6` varchar(255) DEFAULT NULL, + `col_7` decimal(10,0) DEFAULT NULL, + `col_8` varchar(12) DEFAULT NULL, + `col_9` decimal(10,0) DEFAULT NULL, + `col_10` varchar(17) DEFAULT NULL, + `col_11` decimal(10,0) DEFAULT NULL, + `col_12` varchar(7) DEFAULT NULL, + `col_13` date DEFAULT NULL, + `col_14` date DEFAULT NULL, + `col_15` date DEFAULT NULL, + `col_16` date DEFAULT NULL, + `col_17` date DEFAULT NULL, + `col_18` date DEFAULT NULL, + `col_19` date DEFAULT NULL, + `col_20` varchar(1) DEFAULT NULL, + `col_21` varchar(1) DEFAULT NULL, + `col_22` decimal(1,0) DEFAULT NULL, + `col_23` varchar(1) DEFAULT NULL +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; + +CREATE TABLE `table_e` ( + `col_1` varchar(8) NOT NULL, + `col_2` varchar(100) NOT NULL, + `col_3` varchar(100) DEFAULT NULL, + `col_4` varchar(100) NOT NULL, + `col_5` varchar(100) DEFAULT NULL, + `col_6` varchar(100) DEFAULT NULL, + `col_7` decimal(38,12) DEFAULT NULL, + `col_8` varchar(100) DEFAULT NULL, + `col_9` varchar(100) DEFAULT NULL, + `col_10` varchar(100) DEFAULT NULL, + `col_11` varchar(100) DEFAULT NULL, + `col_12` varchar(8) DEFAULT NULL, + `col_13` decimal(38,12) DEFAULT NULL, + `col_14` varchar(100) DEFAULT NULL, + `created_at` timestamp DEFAULT CURRENT_TIMESTAMP, + `col_15` varchar(500) DEFAULT NULL, + PRIMARY KEY (`col_2`, `col_1`, `col_4`), + KEY `index_col_5_6` (`col_5`, `col_6`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; + +INSERT INTO `table_a` +(`col_1`, `col_2`, `col_3`, `col_4`, `col_5`, `col_6`, `col_7`, + `col_8`, `col_9`, `col_10`, `col_11`, `col_12`, `col_13`, + `col_14`, `col_15`, `col_16`, `col_17`, `col_18`, `col_19`, + `col_20`, `col_21`, `created_at`) +VALUES +('20230628', '20230628', 'Portfolio A', 'Product B', 'Direct', 'USD', + 200000, 150000, 50000, 100000, + 50000, 10000, 5000, 1.2, 0.1, + 0.15, 0.08, 0.02, '2023-06-28', + '2023-06-28', '2025-06-28', CURRENT_TIMESTAMP); + + INSERT INTO `table_b` +(`col_1`, `col_2`, `col_3`, `col_4`, `col_5`, `col_6`, `col_7`, `col_8`, `created_at`) +VALUES +('20240628', 'DR201800093', 'Product A', '申购', 1000, 100000, 95000, 1.1, CURRENT_TIMESTAMP); + +INSERT INTO `table_c` +(`col_1`, `col_2`, `col_3`, `col_4`, `col_5`, `col_6`, `col_7`, + `col_8`, `col_9`, `col_10`, `col_11`, `col_12`, `col_13`, + `col_14`, `col_15`, `col_16`, `col_17`, `col_18`, `col_19`, `created_at`) +VALUES +('20230628', 'Dept A', 'DR201800093', 'Product A', '孵化', 'Strategy 1', + 100000, 100000, 120000, 100, 1.2, + 0.2, 0.15, 0.1, 0.05, 0.08, + '2023-06-28', '2025-06-28', '2Y', CURRENT_TIMESTAMP); + +INSERT INTO `table_d` +(`col_1`, `col_2`, `col_3`, `col_4`, `col_5`, `col_6`, `col_7`, + `col_8`, `col_9`, `col_10`, `col_11`, `col_12`, `col_13`, `col_14`, + `col_15`, `col_16`, `col_17`, `col_18`, `col_19`, `col_20`, `col_21`, + `col_22`, `col_23`) +VALUES +('20240628', '1', '2024-06-28', 'Friday', '28', 'End of Month', 202406, + 'June', 20242, 'Q2', 2024, '2024', '2024-06-27', '2024-05-28', + '2024-03-28', '2023-06-28', '2024-06-27', '2024-06-27', '2024-06-27', + '1', '1', '1', '1'); + + INSERT INTO `table_e` +(`col_1`, `col_2`, `col_3`, `col_4`, `col_5`, `col_6`, `col_7`, + `col_8`, `col_9`, `col_10`, `col_11`, `col_12`, `col_13`, `col_14`, + `created_at`, `col_15`) +VALUES +('20230628', 'CFETS_MID', 'Mid', 'USD/CNY', 'USD', 'CNY', + 7.0, 'Source A', 'Unit A', 'Region A', '2023-06-28 15:00:00', '20230627', + 6.9, 'user_001', CURRENT_TIMESTAMP, 'Exchange rate on 2023-06-28'); + +WITH date_table AS ( + SELECT + d.col_1 AS date, + (SELECT MAX(col_1) + FROM table_c a + WHERE col_1 <= + CONCAT(YEAR(DATE_SUB(d.col_1, INTERVAL 1 YEAR)), + '1231') + AND EXISTS (SELECT 1 + FROM table_d d + WHERE a.col_1 = d.col_1 + AND d.col_2 = 1)) AS date1, + (SELECT MAX(col_1) + FROM table_a a + WHERE col_1 <= CONCAT(YEAR(DATE_SUB(d.col_1, INTERVAL 1 YEAR)), + '1231') + AND EXISTS (SELECT 1 + FROM table_d d + WHERE a.col_1 = d.col_1 + AND d.col_2 = 1)) AS date2, + (SELECT MAX(col_1) + FROM table_c + WHERE col_1 <= d.col_1) AS date3, + (SELECT MAX(col_1) + FROM table_a + WHERE col_1 <= d.col_1) AS date4 + FROM table_d d + WHERE d.col_1 = '20240628' +), +rm_am_champs_ex_risk_portfolio_seed_money_1 AS ( + SELECT b.col_2 + FROM table_a b + LEFT JOIN table_e rb + ON rb.col_1 = b.col_19 + AND b.col_6 = rb.col_3 + WHERE b.col_2 = (SELECT date4 FROM date_table) +), + +rm_am_champs_ex_risk_portfolio_seed_money_2 AS ( + SELECT b.col_2 + FROM table_a b + LEFT JOIN table_e rb + ON rb.col_1 = b.col_19 + AND b.col_6 = rb.col_3 +), + +product_base AS ( + SELECT DISTINCT t.col_3, col_4, 'ML' AS is_do + FROM table_c t +), + +product_detail AS ( + SELECT t.col_4, + "3集合" AS nature_investment + FROM product_base t + LEFT JOIN date_table dt + ON 1 = 1 + LEFT JOIN table_c a + ON t.col_4 = a.col_4 + AND a.col_1 = dt.date3 +) + +SELECT col_4 + FROM ( + SELECT col_4 + FROM product_detail + UNION ALL + SELECT col_4 + FROM product_detail +) a; + diff --git a/planner/core/rule_decorrelate.go b/planner/core/rule_decorrelate.go index e3843a4194c29..7093d3717e1b2 100644 --- a/planner/core/rule_decorrelate.go +++ b/planner/core/rule_decorrelate.go @@ -129,28 +129,24 @@ func ExtractCorrelatedCols4PhysicalPlan(p PhysicalPlan) []*expression.Correlated // |_ outerSide // |_ innerSide(cor_col_3) func ExtractOuterApplyCorrelatedCols(p PhysicalPlan) []*expression.CorrelatedColumn { - return extractOuterApplyCorrelatedColsHelper(p, []*expression.Schema{}) + corCols, _ := extractOuterApplyCorrelatedColsHelper(p) + return corCols } -func extractOuterApplyCorrelatedColsHelper(p PhysicalPlan, outerSchemas []*expression.Schema) []*expression.CorrelatedColumn { +func extractOuterApplyCorrelatedColsHelper(p PhysicalPlan) ([]*expression.CorrelatedColumn, []*expression.Schema) { if p == nil { - return nil + return nil, nil } - curCorCols := p.ExtractCorrelatedCols() - newCorCols := make([]*expression.CorrelatedColumn, 0, len(curCorCols)) - // If a corresponding Apply is found inside this PhysicalPlan, ignore it. - for _, corCol := range curCorCols { - var found bool - for _, outerSchema := range outerSchemas { - if outerSchema.ColumnIndex(&corCol.Column) != -1 { - found = true - break - } - } - if !found { - newCorCols = append(newCorCols, corCol) - } + // allCorCols store all sub plan's correlated columns. + // allOuterSchemas store all child Apply's outer side schemas. + allCorCols := p.ExtractCorrelatedCols() + allOuterSchemas := []*expression.Schema{} + + handler := func(child PhysicalPlan) { + childCorCols, childOuterSchemas := extractOuterApplyCorrelatedColsHelper(child) + allCorCols = append(allCorCols, childCorCols...) + allOuterSchemas = append(allOuterSchemas, childOuterSchemas...) } switch v := p.(type) { @@ -161,19 +157,35 @@ func extractOuterApplyCorrelatedColsHelper(p PhysicalPlan, outerSchemas []*expre } else { outerPlan = v.Children()[0] } - outerSchemas = append(outerSchemas, outerPlan.Schema()) - newCorCols = append(newCorCols, extractOuterApplyCorrelatedColsHelper(v.Children()[0], outerSchemas)...) - newCorCols = append(newCorCols, extractOuterApplyCorrelatedColsHelper(v.Children()[1], outerSchemas)...) + allOuterSchemas = append(allOuterSchemas, outerPlan.Schema()) + handler(v.Children()[0]) + handler(v.Children()[1]) case *PhysicalCTE: - newCorCols = append(newCorCols, extractOuterApplyCorrelatedColsHelper(v.SeedPlan, outerSchemas)...) - newCorCols = append(newCorCols, extractOuterApplyCorrelatedColsHelper(v.RecurPlan, outerSchemas)...) + handler(v.SeedPlan) + handler(v.RecurPlan) default: for _, child := range p.Children() { - newCorCols = append(newCorCols, extractOuterApplyCorrelatedColsHelper(child, outerSchemas)...) + handler(child) } } - return newCorCols + resCorCols := make([]*expression.CorrelatedColumn, 0, len(allCorCols)) + + // If one correlated column is found in allOuterSchemas, it means this correlated column is corresponding to an Apply inside `p`. + // However, we only need the correlated columns that correspond to the Apply of the parent node of `p`. + for _, corCol := range allCorCols { + var found bool + for _, outerSchema := range allOuterSchemas { + if outerSchema.ColumnIndex(&corCol.Column) != -1 { + found = true + break + } + } + if !found { + resCorCols = append(resCorCols, corCol) + } + } + return resCorCols, allOuterSchemas } // decorrelateSolver tries to convert apply plan to join plan.