blob: bd10d75b8b6c45a338552cea83e98c3fe74871db [file] [log] [blame]
buyingyic73348c2012-11-02 00:31:31 +00001-- create tables and load data
2create 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/100/customer';
3Create 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/100/lineitem';
4create 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/100/orders';
5create 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/100/supplier';
6create 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/100/nation';
7create external table region (R_REGIONKEY INT, R_NAME STRING, R_COMMENT STRING) ROW FORMAT DELIMITED FIELDS TERMINATED BY '|' STORED AS TEXTFILE LOCATION '/tpch/100/region';
8
9-- create the target table
10create table q5_local_supplier_volume (N_NAME STRING, REVENUE DOUBLE);
11
12set mapred.min.split.size=536870912;
13
14-- the query
15insert overwrite table q5_local_supplier_volume
16select
17 n_name, sum(l_extendedprice * (1 - l_discount)) as revenue
18from
19 customer c join
20 ( select n_name, l_extendedprice, l_discount, s_nationkey, o_custkey from orders o join
21 ( select n_name, l_extendedprice, l_discount, l_orderkey, s_nationkey from lineitem l join
22 ( select n_name, s_suppkey, s_nationkey from supplier s join
23 ( select n_name, n_nationkey
24 from nation n join region r
25 on n.n_regionkey = r.r_regionkey and r.r_name = 'ASIA'
26 ) n1 on s.s_nationkey = n1.n_nationkey
27 ) s1 on l.l_suppkey = s1.s_suppkey
28 ) l1 on l1.l_orderkey = o.o_orderkey and o.o_orderdate >= '1994-01-01'
29 and o.o_orderdate < '1995-01-01'
30) o1
31on c.c_nationkey = o1.s_nationkey and c.c_custkey = o1.o_custkey
32group by n_name
33order by revenue desc;
34
35DROP TABLE customer;
36DROP TABLE orders;
37DROP TABLE lineitem;
38DROP TABLE supplier;
39DROP TABLE nation;
40DROP TABLE region;
41DROP TABLE q5_local_supplier_volume;