buyingyi | c73348c | 2012-11-02 00:31:31 +0000 | [diff] [blame] | 1 | DROP TABLE partsupp; |
| 2 | DROP TABLE part; |
| 3 | DROP TABLE supplier; |
| 4 | DROP TABLE q16_parts_supplier_relationship; |
| 5 | DROP TABLE q16_tmp; |
| 6 | DROP TABLE supplier_tmp; |
| 7 | |
| 8 | -- create the tables and load the data |
| 9 | create external table part (P_PARTKEY INT, P_NAME STRING, P_MFGR STRING, P_BRAND STRING, P_TYPE STRING, P_SIZE INT, P_CONTAINER STRING, P_RETAILPRICE DOUBLE, P_COMMENT STRING) ROW FORMAT DELIMITED FIELDS TERMINATED BY '|' STORED AS TEXTFILE LOCATION '/tpch/10/part'; |
| 10 | create external table partsupp (PS_PARTKEY INT, PS_SUPPKEY INT, PS_AVAILQTY INT, PS_SUPPLYCOST DOUBLE, PS_COMMENT STRING) ROW FORMAT DELIMITED FIELDS TERMINATED BY '|' STORED AS TEXTFILE LOCATION'/tpch/10/partsupp'; |
| 11 | create 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'; |
| 12 | |
| 13 | -- create the result table |
| 14 | create table q16_parts_supplier_relationship(p_brand string, p_type string, p_size int, supplier_cnt int); |
| 15 | create table q16_tmp(p_brand string, p_type string, p_size int, ps_suppkey int); |
| 16 | create table supplier_tmp(s_suppkey int); |
| 17 | |
| 18 | -- the query |
| 19 | insert overwrite table supplier_tmp |
| 20 | select |
| 21 | s_suppkey |
| 22 | from |
| 23 | supplier |
| 24 | where |
| 25 | not s_comment like '%Customer%Complaints%'; |
| 26 | |
| 27 | insert overwrite table q16_tmp |
| 28 | select |
| 29 | p_brand, p_type, p_size, ps_suppkey |
| 30 | from |
| 31 | partsupp ps join part p |
| 32 | on |
| 33 | p.p_partkey = ps.ps_partkey and p.p_brand <> 'Brand#45' |
| 34 | and not p.p_type like 'MEDIUM POLISHED%' |
| 35 | join supplier_tmp s |
| 36 | on |
| 37 | ps.ps_suppkey = s.s_suppkey; |
| 38 | |
| 39 | insert overwrite table q16_parts_supplier_relationship |
| 40 | select |
| 41 | p_brand, p_type, p_size, count(distinct ps_suppkey) as supplier_cnt |
| 42 | from |
| 43 | (select |
| 44 | * |
| 45 | from |
| 46 | q16_tmp |
| 47 | where p_size = 49 or p_size = 14 or p_size = 23 or |
| 48 | p_size = 45 or p_size = 19 or p_size = 3 or |
| 49 | p_size = 36 or p_size = 9 |
| 50 | ) q16_all |
| 51 | group by p_brand, p_type, p_size |
| 52 | order by supplier_cnt desc, p_brand, p_type, p_size; |
| 53 | |