blob: f61bd79da86db696b36ddc36f62b5ed8c9ff7ab1 [file] [log] [blame]
buyingyic73348c2012-11-02 00:31:31 +00001-- create the tables and load the data
2create 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';
3create 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';
4create 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';
5
6-- create the result tables
7create table q18_tmp(l_orderkey int, t_sum_quantity double);
8create table q18_large_volume_customer(c_name string, c_custkey int, o_orderkey int, o_orderdate string, o_totalprice double, sum_quantity double);
9
10set mapred.min.split.size=268435456;
11set hive.exec.reducers.bytes.per.reducer=1164000000;
12
13-- the query
14insert overwrite table q18_tmp
15select
16 l_orderkey, sum(l_quantity) as t_sum_quantity
17from
18 lineitem
19group by l_orderkey;
20
21insert overwrite table q18_large_volume_customer
22select
23 c_name,c_custkey,o_orderkey,o_orderdate,o_totalprice,sum(l_quantity)
24from
25 customer c join orders o
26 on
27 c.c_custkey = o.o_custkey
28 join q18_tmp t
29 on
30 o.o_orderkey = t.l_orderkey and t.t_sum_quantity > 300
31 join lineitem l
32 on
33 o.o_orderkey = l.l_orderkey
34group by c_name,c_custkey,o_orderkey,o_orderdate,o_totalprice
35order by o_totalprice desc,o_orderdate
36limit 100;
37
38DROP TABLE lineitem;
39DROP TABLE orders;
40DROP TABLE customer;
41DROP TABLE q18_tmp;
42DROP TABLE q18_large_volume_customer;