Explorar el Código

rewrite TPC-H q17 using CTEs

Gopal V hace 10 años
padre
commit
235a4ca041
Se han modificado 1 ficheros con 25 adiciones y 33 borrados
  1. 25 33
      sample-queries-tpch/tpch_query17.sql

+ 25 - 33
sample-queries-tpch/tpch_query17.sql

@@ -1,33 +1,25 @@
-drop view q17_lineitem_tmp_cached;
-
-create view q17_lineitem_tmp_cached as
-select
-	l_partkey as t_partkey,
-	0.2 * avg(l_quantity) as t_avg_quantity
-from
-	lineitem
-group by l_partkey;
-
-select
-	sum(l_extendedprice) / 7.0 as avg_yearly
-from (
-	select
-		l_quantity,
-		l_extendedprice,
-		t_avg_quantity
-	from
-		q17_lineitem_tmp_cached join
-		(select
-			l_quantity,
-			l_partkey,
-			l_extendedprice
-		from
-			part,
-			lineitem
-		where
-			p_partkey = l_partkey
-			and p_brand = 'Brand#23'
-			and p_container = 'MED BOX'
-		) l1 on l1.l_partkey = t_partkey
-) a 
-where l_quantity < t_avg_quantity;
+with q17_part as (
+  select p_partkey from part where  
+  p_brand = 'Brand#23'
+  and p_container = 'MED BOX'
+),
+q17_avg as (
+  select l_partkey as t_partkey, 0.2 * avg(l_quantity) as t_avg_quantity
+  from lineitem 
+  where l_partkey IN (select p_partkey from q17_part)
+  group by l_partkey
+),
+q17_price as (
+  select
+  l_quantity,
+  l_partkey,
+  l_extendedprice
+  from
+  lineitem
+  where
+  l_partkey IN (select p_partkey from q17_part)
+)
+select cast(sum(l_extendedprice) / 7.0 as decimal(32,2)) as avg_yearly
+from q17_avg, q17_price
+where 
+t_partkey = l_partkey and l_quantity < t_avg_quantity;