[Query Plan]Support simple transitivity on join predicate pushdown (#3453)
Current implement is very simply and conservative, because our query planner is error-prone. After we implement the new query planner, we could do this work by `Predicate Equivalence Class` and `PredicatePushDown` rule like presto.
This commit is contained in:
@ -98,6 +98,32 @@ public class QueryPlanTest {
|
||||
" \"replication_num\" = \"1\"\n" +
|
||||
");");
|
||||
|
||||
createTable("CREATE TABLE test.join1 (\n" +
|
||||
" `dt` int(11) COMMENT \"\",\n" +
|
||||
" `id` int(11) COMMENT \"\",\n" +
|
||||
" `value` varchar(8) COMMENT \"\"\n" +
|
||||
") ENGINE=OLAP\n" +
|
||||
"DUPLICATE KEY(`dt`, `id`)\n" +
|
||||
"PARTITION BY RANGE(`dt`)\n" +
|
||||
"(PARTITION p1 VALUES LESS THAN (\"10\"))\n" +
|
||||
"DISTRIBUTED BY HASH(`id`) BUCKETS 10\n" +
|
||||
"PROPERTIES (\n" +
|
||||
" \"replication_num\" = \"1\"\n" +
|
||||
");");
|
||||
|
||||
createTable("CREATE TABLE test.join2 (\n" +
|
||||
" `dt` int(11) COMMENT \"\",\n" +
|
||||
" `id` int(11) COMMENT \"\",\n" +
|
||||
" `value` varchar(8) COMMENT \"\"\n" +
|
||||
") ENGINE=OLAP\n" +
|
||||
"DUPLICATE KEY(`dt`, `id`)\n" +
|
||||
"PARTITION BY RANGE(`dt`)\n" +
|
||||
"(PARTITION p1 VALUES LESS THAN (\"10\"))\n" +
|
||||
"DISTRIBUTED BY HASH(`id`) BUCKETS 10\n" +
|
||||
"PROPERTIES (\n" +
|
||||
" \"replication_num\" = \"1\"\n" +
|
||||
");");
|
||||
|
||||
createTable("CREATE TABLE test.bitmap_table_2 (\n" +
|
||||
" `id` int(11) NULL COMMENT \"\",\n" +
|
||||
" `id2` bitmap bitmap_union NULL\n" +
|
||||
@ -504,4 +530,104 @@ public class QueryPlanTest {
|
||||
Catalog.getCurrentCatalog().getLoadManager().createLoadJobV1FromStmt(loadStmt, EtlJobType.HADOOP,
|
||||
System.currentTimeMillis());
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testJoinPredicateTransitivity() throws Exception {
|
||||
connectContext.setDatabase("default_cluster:test");
|
||||
|
||||
// test left join : left table where binary predicate
|
||||
String sql = "select join1.id\n" +
|
||||
"from join1\n" +
|
||||
"left join join2 on join1.id = join2.id\n" +
|
||||
"where join1.id > 1;";
|
||||
String explainString = UtFrameUtils.getSQLPlanOrErrorMsg(connectContext, "explain " + sql);
|
||||
System.out.println(explainString);
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join2`.`id` > 1"));
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join1`.`id` > 1"));
|
||||
|
||||
// test left join: left table where in predicate
|
||||
sql = "select join1.id\n" +
|
||||
"from join1\n" +
|
||||
"left join join2 on join1.id = join2.id\n" +
|
||||
"where join1.id in (2);";
|
||||
explainString = UtFrameUtils.getSQLPlanOrErrorMsg(connectContext, "explain " + sql);
|
||||
System.out.println(explainString);
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join2`.`id` IN (2)"));
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join1`.`id` IN (2)"));
|
||||
|
||||
// test left join: left table where between predicate
|
||||
sql = "select join1.id\n" +
|
||||
"from join1\n" +
|
||||
"left join join2 on join1.id = join2.id\n" +
|
||||
"where join1.id BETWEEN 1 AND 2;";
|
||||
explainString = UtFrameUtils.getSQLPlanOrErrorMsg(connectContext, "explain " + sql);
|
||||
System.out.println(explainString);
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join1`.`id` >= 1, `join1`.`id` <= 2"));
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join2`.`id` >= 1, `join2`.`id` <= 2"));
|
||||
|
||||
// test left join: left table join predicate, left table couldn't push down
|
||||
sql = "select *\n from join1\n" +
|
||||
"left join join2 on join1.id = join2.id\n" +
|
||||
"and join1.id > 1;";
|
||||
explainString = UtFrameUtils.getSQLPlanOrErrorMsg(connectContext, "explain " + sql);
|
||||
System.out.println(explainString);
|
||||
Assert.assertTrue(explainString.contains("other join predicates: `join1`.`id` > 1"));
|
||||
Assert.assertFalse(explainString.contains("PREDICATES: `join1`.`id` > 1"));
|
||||
|
||||
// test left join: right table where predicate.
|
||||
// If we eliminate outer join, we could push predicate down to join1 and join2.
|
||||
// Currently, we push predicate to join1 and keep join predicate for join2
|
||||
sql = "select *\n from join1\n" +
|
||||
"left join join2 on join1.id = join2.id\n" +
|
||||
"where join2.id > 1;";
|
||||
explainString = UtFrameUtils.getSQLPlanOrErrorMsg(connectContext, "explain " + sql);
|
||||
System.out.println(explainString);
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join1`.`id` > 1"));
|
||||
Assert.assertFalse(explainString.contains("other join predicates: `join2`.`id` > 1"));
|
||||
|
||||
// test left join: right table join predicate, only push down right table
|
||||
sql = "select *\n from join1\n" +
|
||||
"left join join2 on join1.id = join2.id\n" +
|
||||
"and join2.id > 1;";
|
||||
explainString = UtFrameUtils.getSQLPlanOrErrorMsg(connectContext, "explain " + sql);
|
||||
System.out.println(explainString);
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join2`.`id` > 1"));
|
||||
Assert.assertFalse(explainString.contains("PREDICATES: `join1`.`id` > 1"));
|
||||
|
||||
// test inner join: left table where predicate, both push down left table and right table
|
||||
sql = "select *\n from join1\n" +
|
||||
"join join2 on join1.id = join2.id\n" +
|
||||
"where join1.id > 1;";
|
||||
explainString = UtFrameUtils.getSQLPlanOrErrorMsg(connectContext, "explain " + sql);
|
||||
System.out.println(explainString);
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join1`.`id` > 1"));
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join2`.`id` > 1"));
|
||||
|
||||
// test inner join: left table join predicate, both push down left table and right table
|
||||
sql = "select *\n from join1\n" +
|
||||
"join join2 on join1.id = join2.id\n" +
|
||||
"and join1.id > 1;";
|
||||
explainString = UtFrameUtils.getSQLPlanOrErrorMsg(connectContext, "explain " + sql);
|
||||
System.out.println(explainString);
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join1`.`id` > 1"));
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join2`.`id` > 1"));
|
||||
|
||||
// test inner join: right table where predicate, both push down left table and right table
|
||||
sql = "select *\n from join1\n" +
|
||||
"join join2 on join1.id = join2.id\n" +
|
||||
"where join2.id > 1;";
|
||||
explainString = UtFrameUtils.getSQLPlanOrErrorMsg(connectContext, "explain " + sql);
|
||||
System.out.println(explainString);
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join1`.`id` > 1"));
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join2`.`id` > 1"));
|
||||
|
||||
// test inner join: right table join predicate, both push down left table and right table
|
||||
sql = "select *\n from join1\n" +
|
||||
"join join2 on join1.id = join2.id\n" +
|
||||
"and join2.id > 1;";
|
||||
explainString = UtFrameUtils.getSQLPlanOrErrorMsg(connectContext, "explain " + sql);
|
||||
System.out.println(explainString);
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join1`.`id` > 1"));
|
||||
Assert.assertTrue(explainString.contains("PREDICATES: `join2`.`id` > 1"));
|
||||
}
|
||||
}
|
||||
|
||||
Reference in New Issue
Block a user