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