-- -- Name: Nicholas Tamassia -- -- Write your queries below each comment. Please use good style (one clause -- per line, JOIN syntax, indentation) and make sure all queries end with a -- semicolon. When necessary, limit the output to the first 200 results. -- -- DO NOT MODIFY OR DELETE ANY OTHER LINES! -- -- ----------------------------------------------------------------------------- -- Connect to tpch database \c tpch -- ----------------------------------------------------------------------------- -- \echo \echo Query #1 -- -- Show the customer name, order date, and line items for order number 3. -- -- Schema: c_name, o_orderdate, l_partkey, l_suppkey, l_quantity, l_extendedPrice -- Order: l_linenumber SELECT c_name, o_orderdate, l_partkey, l_suppkey, l_quantity, l_extendedPrice FROM customer JOIN orders ON c_custkey = o_custkey JOIN lineitem ON o_orderkey = l_orderkey WHERE o_orderkey = 3 ORDER BY l_linenumber LIMIT 200; -- \echo \echo Query #2 -- -- Show the part name, supply cost, and retail price of each line item. -- -- Schema: l_orderkey, l_partkey, l_suppkey, p_name, ps_supplycost, p_retailprice -- Order: l_orderkey, l_linenumber SELECT l_orderkey, l_partkey, l_suppkey, p_name, ps_supplycost, p_retailprice FROM lineitem JOIN partsupp ON (l_partkey = ps_partkey AND l_suppkey = ps_suppkey) JOIN part ON ps_partkey = p_partkey ORDER BY l_orderkey, l_linenumber LIMIT 200; -- \echo \echo Query #3 -- -- Which customers with an account balance over 5000 have no orders? -- -- Schema: c_name, c_acctbal -- Order: c_custkey SELECT c_name, c_acctbal FROM customer LEFT JOIN orders ON c_custkey = o_custkey WHERE c_acctbal > 5000 AND o_orderkey is NULL ORDER BY c_custkey LIMIT 200; -- \echo \echo Query #4 -- -- Which urgent priority orders have only one line item? -- -- Schema: o_orderkey, o_custkey, o_orderstatus -- Order: o_orderkey SELECT o_orderkey, o_custkey, o_orderstatus FROM orders JOIN lineitem ON o_orderkey = l_orderkey WHERE o_orderpriority = '1-URGENT' GROUP BY o_orderkey HAVING COUNT(l_orderkey) = 1 ORDER BY o_orderkey LIMIT 200; -- \echo \echo Query #5 -- -- What parts containing the word "chocolate" were ordered on or after -- August 1, 1998 and shipped by mail? -- -- Schema: p_name, ps_supplycost, l_quantity -- Order: p_partkey SELECT p_name, ps_supplycost, l_quantity FROM part JOIN partsupp ON p_partkey = ps_partkey JOIN lineitem ON (ps_partkey = l_partkey AND ps_suppkey = l_suppkey) JOIN orders ON l_orderkey = o_orderkey WHERE p_name LIKE '%chocolate%' AND o_orderdate >= '1998-08-01' AND l_shipmode = 'MAIL' ORDER BY p_partkey LIMIT 200; -- \echo \echo Query #6 -- -- Get the min, max, and average supply cost of each part. The average supply cost -- must be rounded to 2 decimal places. -- -- Schema: p_name, p_retailprice, min_supplycost, max_supplycost, avg_supplycost -- Order: p_partkey SELECT p_name, p_retailprice, MIN(ps_supplycost) AS "min_supplycost", MAX(ps_supplycost) AS "max_supplycost", ROUND(AVG(ps_supplycost), 2) as "avg_supplycost" FROM part JOIN partsupp on p_partkey = ps_partkey GROUP BY p_partkey ORDER BY p_partkey LIMIT 200; -- \echo \echo Query #7 -- -- What suppliers have an inventory (total available quantity) of over 125,000 -- parts with size over 40. -- -- Schema: r_name, n_name, s_name, total_qty -- Order: r_name, n_name, s_name SELECT r_name, n_name, s_name, SUM(ps_availqty) AS "total_qty" FROM supplier JOIN partsupp ON s_suppkey = ps_suppkey JOIN part ON ps_partkey = p_partkey JOIN nation ON s_nationkey = n_nationkey JOIN region ON n_regionkey = r_regionkey WHERE p_size > 40 GROUP BY s_name, n_name, r_name HAVING SUM(ps_availqty) > 125000 ORDER BY r_name, n_name, s_name LIMIT 200; -- \echo \echo Query #8 -- -- Find orders with a total profit of over $375,000. The profit of a single -- lineitem is defined as quantity * (retail price - supply cost). The profit -- of an order is the sum of its lineitem profits. For each order, show also -- the number of lineitems, the total quantity of items (rounded to 0 decimal -- places), and the total profit of the order (rounded to 2 decimal places). -- -- Schema: l_orderkey, num_lineitems, total_quantity, total_profit -- Order: total_profit (descending), total_quantity SELECT l_orderkey, COUNT(l_quantity) AS "num_lineitems", ROUND(SUM(l_quantity)) AS "total_quantity", ROUND(SUM(l_quantity * (p_retailprice - ps_supplycost)), 2) AS "total_profit" FROM orders JOIN lineitem ON o_orderkey = l_orderkey JOIN partsupp ON (l_partkey = ps_partkey AND l_suppkey = ps_suppkey) JOIN part ON ps_partkey = p_partkey GROUP BY l_orderkey HAVING SUM(l_quantity * (p_retailprice - ps_supplycost)) > 375000 ORDER BY "total_profit" DESC, "total_quantity" LIMIT 200;