blob: 381aa9f0cf89d9276a308fa67dec0b988a8115bb [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 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';
4
5-- create target tables
6create table q22_customer_tmp(c_acctbal double, c_custkey int, cntrycode string);
7create table q22_customer_tmp1(avg_acctbal double);
8create table q22_orders_tmp(o_custkey int);
9create table q22_global_sales_opportunity(cntrycode string, numcust int, totacctbal double);
10
11-- the query
12insert overwrite table q22_customer_tmp
13select
14 c_acctbal, c_custkey, substr(c_phone, 1, 2) as cntrycode
15from
16 customer
17where
18 substr(c_phone, 1, 2) = '13' or
19 substr(c_phone, 1, 2) = '31' or
20 substr(c_phone, 1, 2) = '23' or
21 substr(c_phone, 1, 2) = '29' or
22 substr(c_phone, 1, 2) = '30' or
23 substr(c_phone, 1, 2) = '18' or
24 substr(c_phone, 1, 2) = '17';
25
26insert overwrite table q22_customer_tmp1
27select
28 avg(c_acctbal)
29from
30 q22_customer_tmp
31where
32 c_acctbal > 0.00;
33
34insert overwrite table q22_orders_tmp
35select
36 o_custkey
37from
38 orders
39group by
40 o_custkey;
41
42insert overwrite table q22_global_sales_opportunity
43select
44 cntrycode, count(1) as numcust, sum(c_acctbal) as totacctbal
45from
46(
47 select cntrycode, c_acctbal, avg_acctbal from
48 q22_customer_tmp1 ct1 join
49 (
50 select cntrycode, c_acctbal from
51 q22_orders_tmp ot
52 right outer join q22_customer_tmp ct
53 on
54 ct.c_custkey = ot.o_custkey
55 where
56 o_custkey is null
57 ) ct2
58) a
59where
60 c_acctbal > avg_acctbal
61group by cntrycode
62order by cntrycode;
63
64DROP TABLE customer;
65DROP TABLE orders;
66DROP TABLE q22_customer_tmp;
67DROP TABLE q22_customer_tmp1;
68DROP TABLE q22_orders_tmp;
69DROP TABLE q22_global_sales_opportunity;