Description
Plan for TPC-DS Q64 wasn't optimal upon looking at the logical plan I realized that predicate pushdown is not applied on date_dim d1.
Interestingly before optiq we have the predicate pushed :
HiveFilterRel(condition=[<=($5, $1)]) HiveJoinRel(condition=[=($3, $6)], joinType=[inner]) HiveProjectRel(_o__col0=[$0], _o__col1=[$2], _o__col2=[$3], _o__col3=[$1]) HiveFilterRel(condition=[=($0, 2000)]) HiveAggregateRel(group=[{0, 1}], agg#0=[count()], agg#1=[sum($2)]) HiveProjectRel($f0=[$4], $f1=[$5], $f2=[$2]) HiveJoinRel(condition=[=($1, $8)], joinType=[inner]) HiveJoinRel(condition=[=($1, $5)], joinType=[inner]) HiveJoinRel(condition=[=($0, $3)], joinType=[inner]) HiveProjectRel(ss_sold_date_sk=[$0], ss_item_sk=[$2], ss_wholesale_cost=[$11]) HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.store_sales]]) HiveProjectRel(d_date_sk=[$0], d_year=[$6]) HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.date_dim]]) HiveFilterRel(condition=[AND(in($2, 'maroon', 'burnished', 'dim', 'steel', 'navajo', 'chocolate'), between(false, $1, 35, +(35, 10)), between(false, $1, +(35, 1), +(35, 15)))]) HiveProjectRel(i_item_sk=[$0], i_current_price=[$5], i_color=[$17]) HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.item]]) HiveProjectRel(_o__col0=[$0]) HiveAggregateRel(group=[{0}]) HiveProjectRel($f0=[$0]) HiveJoinRel(condition=[AND(=($0, $2), =($1, $3))], joinType=[inner]) HiveProjectRel(cs_item_sk=[$15], cs_order_number=[$17]) HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.catalog_sales]]) HiveProjectRel(cr_item_sk=[$2], cr_order_number=[$16]) HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.catalog_returns]]) HiveProjectRel(_o__col0=[$0], _o__col1=[$2], _o__col3=[$1]) HiveFilterRel(condition=[=($0, +(2000, 1))]) HiveAggregateRel(group=[{0, 1}], agg#0=[count()]) HiveProjectRel($f0=[$4], $f1=[$5], $f2=[$2]) HiveJoinRel(condition=[=($1, $8)], joinType=[inner]) HiveJoinRel(condition=[=($1, $5)], joinType=[inner]) HiveJoinRel(condition=[=($0, $3)], joinType=[inner]) HiveProjectRel(ss_sold_date_sk=[$0], ss_item_sk=[$2], ss_wholesale_cost=[$11]) HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.store_sales]]) HiveProjectRel(d_date_sk=[$0], d_year=[$6]) HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.date_dim]]) HiveFilterRel(condition=[AND(in($2, 'maroon', 'burnished', 'dim', 'steel', 'navajo', 'chocolate'), between(false, $1, 35, +(35, 10)), between(false, $1, +(35, 1), +(35, 15)))]) HiveProjectRel(i_item_sk=[$0], i_current_price=[$5], i_color=[$17]) HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.item]]) HiveProjectRel(_o__col0=[$0]) HiveAggregateRel(group=[{0}]) HiveProjectRel($f0=[$0]) HiveJoinRel(condition=[AND(=($0, $2), =($1, $3))], joinType=[inner]) HiveProjectRel(cs_item_sk=[$15], cs_order_number=[$17]) HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.catalog_sales]]) HiveProjectRel(cr_item_sk=[$2], cr_order_number=[$16]) HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.catalog_returns]])
While after Optiq the filter on date_dim gets pulled up the plan
HiveFilterRel(condition=[<=($5, $1)]): rowcount = 1.0, cumulative cost = {5.50188454E8 rows, 0.0 cpu, 0.0 io}, id = 6895 HiveProjectRel(_o__col0=[$0], _o__col1=[$1], _o__col2=[$2], _o__col3=[$3], _o__col00=[$4], _o__col10=[$5], _o__col30=[$6]): rowcount = 1.0, cumulative cost = {5.50188454E8 rows, 0.0 cpu, 0.0 io}, id = 7046 HiveJoinRel(condition=[=($3, $6)], joinType=[inner]): rowcount = 1.0, cumulative cost = {5.50188454E8 rows, 0.0 cpu, 0.0 io}, id = 7041 HiveProjectRel(_o__col0=[$0], _o__col1=[$2], _o__col2=[$3], _o__col3=[$1]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 6857 HiveFilterRel(condition=[=($0, 2000)]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 6855 HiveAggregateRel(group=[{0, 1}], agg#0=[count()], agg#1=[sum($2)]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 6853 HiveProjectRel($f0=[$4], $f1=[$5], $f2=[$2]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 6851 HiveProjectRel(ss_sold_date_sk=[$3], ss_item_sk=[$4], ss_wholesale_cost=[$5], d_date_sk=[$0], d_year=[$1], i_item_sk=[$6], i_current_price=[$7], i_color=[$8], _o__col0=[$2]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 7039 HiveJoinRel(condition=[=($3, $0)], joinType=[inner]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 7037 HiveProjectRel(d_date_sk=[$0], d_year=[$6]): rowcount = 73049.0, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6861 HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.date_dim]]): rowcount = 73049.0, cumulative cost = {0}, id = 6537 HiveJoinRel(condition=[=($2, $0)], joinType=[inner]): rowcount = 1.0, cumulative cost = {5.50115402E8 rows, 0.0 cpu, 0.0 io}, id = 7035 HiveProjectRel(_o__col0=[$0]): rowcount = 38846.0, cumulative cost = {3.15348608E8 rows, 0.0 cpu, 0.0 io}, id = 6847 HiveAggregateRel(group=[{0}]): rowcount = 38846.0, cumulative cost = {3.15348608E8 rows, 0.0 cpu, 0.0 io}, id = 6845 HiveProjectRel($f0=[$0]): rowcount = 6.692553251460564E8, cumulative cost = {3.15348608E8 rows, 0.0 cpu, 0.0 io}, id = 6843 HiveProjectRel(cs_item_sk=[$0], cs_order_number=[$1], cr_item_sk=[$2], cr_order_number=[$3]): rowcount = 6.692553251460564E8, cumulative cost = {3.15348608E8 rows, 0.0 cpu, 0.0 io}, id = 6945 HiveJoinRel(condition=[AND(=($0, $2), =($1, $3))], joinType=[inner]): rowcount = 6.692553251460564E8, cumulative cost = {3.15348608E8 rows, 0.0 cpu, 0.0 io}, id = 6940 HiveProjectRel(cs_item_sk=[$15], cs_order_number=[$17]): rowcount = 2.86549727E8, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6871 HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.catalog_sales]]): rowcount = 2.86549727E8, cumulative cost = {0}, id = 6531 HiveProjectRel(cr_item_sk=[$2], cr_order_number=[$16]): rowcount = 2.8798881E7, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6873 HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.catalog_returns]]): rowcount = 2.8798881E7, cumulative cost = {0}, id = 6532 HiveJoinRel(condition=[=($1, $3)], joinType=[inner]): rowcount = 1.0, cumulative cost = {5.50076555E8 rows, 0.0 cpu, 0.0 io}, id = 6996 HiveProjectRel(ss_sold_date_sk=[$0], ss_item_sk=[$2], ss_wholesale_cost=[$11]): rowcount = 5.50076554E8, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6859 HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.store_sales]]): rowcount = 5.50076554E8, cumulative cost = {0}, id = 6538 HiveFilterRel(condition=[AND(in($2, 'maroon', 'burnished', 'dim', 'steel', 'navajo', 'chocolate'), between(false, $1, 35, +(35, 10)), between(false, $1, +(35, 1), +(35, 15)))]): rowcount = 1.0, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6833 HiveProjectRel(i_item_sk=[$0], i_current_price=[$5], i_color=[$17]): rowcount = 48000.0, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6831 HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.item]]): rowcount = 48000.0, cumulative cost = {0}, id = 6539 HiveProjectRel(_o__col0=[$0], _o__col1=[$2], _o__col3=[$1]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 6891 HiveFilterRel(condition=[=($0, +(2000, 1))]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 6889 HiveAggregateRel(group=[{0, 1}], agg#0=[count()]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 6887 HiveProjectRel($f0=[$4], $f1=[$5], $f2=[$2]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 6885 HiveProjectRel(ss_sold_date_sk=[$3], ss_item_sk=[$4], ss_wholesale_cost=[$5], d_date_sk=[$0], d_year=[$1], i_item_sk=[$6], i_current_price=[$7], i_color=[$8], _o__col0=[$2]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 6992 HiveJoinRel(condition=[=($3, $0)], joinType=[inner]): rowcount = 1.0, cumulative cost = {5.50188452E8 rows, 0.0 cpu, 0.0 io}, id = 6990 HiveProjectRel(d_date_sk=[$0], d_year=[$6]): rowcount = 73049.0, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6861 HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.date_dim]]): rowcount = 73049.0, cumulative cost = {0}, id = 6537 HiveJoinRel(condition=[=($2, $0)], joinType=[inner]): rowcount = 1.0, cumulative cost = {5.50115402E8 rows, 0.0 cpu, 0.0 io}, id = 6988 HiveProjectRel(_o__col0=[$0]): rowcount = 38846.0, cumulative cost = {3.15348608E8 rows, 0.0 cpu, 0.0 io}, id = 6881 HiveAggregateRel(group=[{0}]): rowcount = 38846.0, cumulative cost = {3.15348608E8 rows, 0.0 cpu, 0.0 io}, id = 6879 HiveProjectRel($f0=[$0]): rowcount = 6.692553251460564E8, cumulative cost = {3.15348608E8 rows, 0.0 cpu, 0.0 io}, id = 6877 HiveProjectRel(cs_item_sk=[$0], cs_order_number=[$1], cr_item_sk=[$2], cr_order_number=[$3]): rowcount = 6.692553251460564E8, cumulative cost = {3.15348608E8 rows, 0.0 cpu, 0.0 io}, id = 6938 HiveJoinRel(condition=[AND(=($0, $2), =($1, $3))], joinType=[inner]): rowcount = 6.692553251460564E8, cumulative cost = {3.15348608E8 rows, 0.0 cpu, 0.0 io}, id = 6933 HiveProjectRel(cs_item_sk=[$15], cs_order_number=[$17]): rowcount = 2.86549727E8, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6871 HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.catalog_sales]]): rowcount = 2.86549727E8, cumulative cost = {0}, id = 6531 HiveProjectRel(cr_item_sk=[$2], cr_order_number=[$16]): rowcount = 2.8798881E7, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6873 HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.catalog_returns]]): rowcount = 2.8798881E7, cumulative cost = {0}, id = 6532 HiveJoinRel(condition=[=($1, $3)], joinType=[inner]): rowcount = 1.0, cumulative cost = {5.50076555E8 rows, 0.0 cpu, 0.0 io}, id = 6949 HiveProjectRel(ss_sold_date_sk=[$0], ss_item_sk=[$2], ss_wholesale_cost=[$11]): rowcount = 5.50076554E8, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6859 HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.store_sales]]): rowcount = 5.50076554E8, cumulative cost = {0}, id = 6538 HiveFilterRel(condition=[AND(in($2, 'maroon', 'burnished', 'dim', 'steel', 'navajo', 'chocolate'), between(false, $1, 35, +(35, 10)), between(false, $1, +(35, 1), +(35, 15)))]): rowcount = 1.0, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6867 HiveProjectRel(i_item_sk=[$0], i_current_price=[$5], i_color=[$17]): rowcount = 48000.0, cumulative cost = {0.0 rows, 0.0 cpu, 0.0 io}, id = 6865 HiveTableScanRel(table=[[tpcds_bin_partitioned_orc_200.item]]): rowcount = 48000.0, cumulative cost = {0}, id = 6539
I simplified the query a little bit while still maintaining the query structure
The query :
Note that the final join between cs1 and cs2 has a predicates "cs1.syear = 2000 and cs2.syear = 2000 + 1"
select cs1.syear ,cs1.cnt ,cs1.s1 ,cs2.syear ,cs2.cnt from (select d1.d_year as syear ,count(*) as cnt,sum(ss_wholesale_cost) as s1 ,i_item_sk as item_sk FROM store_sales JOIN date_dim d1 ON store_sales.ss_sold_date_sk = d1.d_date_sk JOIN item ON store_sales.ss_item_sk = item.i_item_sk JOIN (select cs_item_sk from catalog_sales JOIN catalog_returns ON catalog_sales.cs_item_sk = catalog_returns.cr_item_sk and catalog_sales.cs_order_number = catalog_returns.cr_order_number group by cs_item_sk) cs_ui ON store_sales.ss_item_sk = cs_ui.cs_item_sk WHERE i_color in ('maroon','burnished','dim','steel','navajo','chocolate') and i_current_price between 35 and 35 + 10 and i_current_price between 35 + 1 and 35 + 15 group by d1.d_year,i_item_sk ) cs1 JOIN (select d1.d_year as syear ,count(*) as cnt,sum(ss_wholesale_cost) as s1 , i_item_sk as item_sk FROM store_sales JOIN date_dim d1 ON store_sales.ss_sold_date_sk = d1.d_date_sk JOIN item ON store_sales.ss_item_sk = item.i_item_sk JOIN (select cs_item_sk from catalog_sales JOIN catalog_returns ON catalog_sales.cs_item_sk = catalog_returns.cr_item_sk and catalog_sales.cs_order_number = catalog_returns.cr_order_number group by cs_item_sk) cs_ui ON store_sales.ss_item_sk = cs_ui.cs_item_sk WHERE i_color in ('maroon','burnished','dim','steel','navajo','chocolate') and i_current_price between 35 and 35 + 10 and i_current_price between 35 + 1 and 35 + 15 group by d1.d_year,i_item_sk ) cs2 ON cs1.item_sk=cs2.item_sk where cs1.syear = 2000 and cs2.syear = 2000 + 1 and cs2.cnt <= cs1.cnt;
Attachments
Attachments
Issue Links
- is cloned by
-
HIVE-8263 CBO : TPC-DS Q64 is item is joined last with store_sales while it should be first as it is the most selective
- Closed