blob: da6eab21f40edc618c0fb5a54c4846670eeb8568 [file] [log] [blame]
buyingyic73348c2012-11-02 00:31:31 +00001DROP TABLE customer;
2DROP TABLE orders;
3DROP TABLE lineitem;
4DROP TABLE supplier;
5DROP TABLE nation;
6DROP TABLE q7_volume_shipping;
7DROP TABLE q7_volume_shipping_tmp;
8
9-- create tables and load data
10create external table customer (C_CUSTKEY INT, C_NAME STRING, C_ADDRESS STRING, C_NATIONKEY INT, C_PHONE STRING, C_ACCTBAL DOUBLE, C_MKTSEGMENT STRING, C_COMMENT STRING) ROW FORMAT DELIMITED FIELDS TERMINATED BY '|' STORED AS TEXTFILE LOCATION '/tpch/10/customer';
11Create external table lineitem (L_ORDERKEY INT, L_PARTKEY INT, L_SUPPKEY INT, L_LINENUMBER INT, L_QUANTITY DOUBLE, L_EXTENDEDPRICE DOUBLE, L_DISCOUNT DOUBLE, L_TAX DOUBLE, L_RETURNFLAG STRING, L_LINESTATUS STRING, L_SHIPDATE STRING, L_COMMITDATE STRING, L_RECEIPTDATE STRING, L_SHIPINSTRUCT STRING, L_SHIPMODE STRING, L_COMMENT STRING) ROW FORMAT DELIMITED FIELDS TERMINATED BY '|' STORED AS TEXTFILE LOCATION '/tpch/10/lineitem';
12create external table orders (O_ORDERKEY INT, O_CUSTKEY INT, O_ORDERSTATUS STRING, O_TOTALPRICE DOUBLE, O_ORDERDATE STRING, O_ORDERPRIORITY STRING, O_CLERK STRING, O_SHIPPRIORITY INT, O_COMMENT STRING) ROW FORMAT DELIMITED FIELDS TERMINATED BY '|' STORED AS TEXTFILE LOCATION '/tpch/10/orders';
13create external table supplier (S_SUPPKEY INT, S_NAME STRING, S_ADDRESS STRING, S_NATIONKEY INT, S_PHONE STRING, S_ACCTBAL DOUBLE, S_COMMENT STRING) ROW FORMAT DELIMITED FIELDS TERMINATED BY '|' STORED AS TEXTFILE LOCATION '/tpch/10/supplier';
14create external table nation (N_NATIONKEY INT, N_NAME STRING, N_REGIONKEY INT, N_COMMENT STRING) ROW FORMAT DELIMITED FIELDS TERMINATED BY '|' STORED AS TEXTFILE LOCATION '/tpch/10/nation';
15
16-- create the target table
17create table q7_volume_shipping (supp_nation string, cust_nation string, l_year int, revenue double);
18create table q7_volume_shipping_tmp(supp_nation string, cust_nation string, s_nationkey int, c_nationkey int);
19
20set mapred.min.split.size=536870912;
21set hive.exec.reducers.bytes.per.reducer=1225000000;
22
23-- the query
24insert overwrite table q7_volume_shipping_tmp
25select
26 *
27from
28 (
29 select
30 n1.n_name as supp_nation, n2.n_name as cust_nation, n1.n_nationkey as s_nationkey,
31 n2.n_nationkey as c_nationkey
32from
33 nation n1 join nation n2
34 on
35 n1.n_name = 'FRANCE' and n2.n_name = 'GERMANY'
36 UNION ALL
37select
38 n1.n_name as supp_nation, n2.n_name as cust_nation, n1.n_nationkey as s_nationkey,
39 n2.n_nationkey as c_nationkey
40from
41 nation n1 join nation n2
42 on
43 n2.n_name = 'FRANCE' and n1.n_name = 'GERMANY'
44) a;
45
46insert overwrite table q7_volume_shipping
47select
48 supp_nation, cust_nation, l_year, sum(volume) as revenue
49from
50 (
51 select
52 supp_nation, cust_nation, year(l_shipdate) as l_year,
53 l_extendedprice * (1 - l_discount) as volume
54 from
55 q7_volume_shipping_tmp t join
56 (select l_shipdate, l_extendedprice, l_discount, c_nationkey, s_nationkey
57 from supplier s join
58 (select l_shipdate, l_extendedprice, l_discount, l_suppkey, c_nationkey
59 from customer c join
60 (select l_shipdate, l_extendedprice, l_discount, l_suppkey, o_custkey
61 from orders o join lineitem l
62 on
63 o.o_orderkey = l.l_orderkey and l.l_shipdate >= '1995-01-01'
64 and l.l_shipdate <= '1996-12-31'
65 ) l1 on c.c_custkey = l1.o_custkey
66 ) l2 on s.s_suppkey = l2.l_suppkey
67 ) l3 on l3.c_nationkey = t.c_nationkey and l3.s_nationkey = t.s_nationkey
68 ) shipping
69group by supp_nation, cust_nation, l_year
70order by supp_nation, cust_nation, l_year;
71