From 751d3a2bb5f19aec21251efa46d29f0c5ec349ac Mon Sep 17 00:00:00 2001 From: "Peter J. Keleher" <keleher@cs.umd.edu> Date: Mon, 23 Sep 2019 15:57:50 -0400 Subject: [PATCH] auto --- project1/SQLTesting.py | 21 +++++-- project1/queries.py | 126 +++++++++++++++++++++++++++++++++++++---- 2 files changed, 132 insertions(+), 15 deletions(-) diff --git a/project1/SQLTesting.py b/project1/SQLTesting.py index 6621d4c..6c2809f 100755 --- a/project1/SQLTesting.py +++ b/project1/SQLTesting.py @@ -5,17 +5,24 @@ import datetime from collections import Counter from types import * import argparse +import importlib from queries import * from answers import * parser = argparse.ArgumentParser() parser.add_argument('-v', '--verbose', help="Print out the query results and more details", required=False, action="store_true") +parser.add_argument('-t', '--terse', default="none", help="Just points", required=False) parser.add_argument('-i', '--interactive', help="Run queries one at a time, and wait for user to proceed", required=False, action="store_true") parser.add_argument('-q', '--query', type = int, help="Only run and check the given query number", required=False) parser.add_argument('-g', '--generate', help="Print out the query results and more details", required=False, action="store_true") args = parser.parse_args() +terse = (args.terse != "none") + +if terse: + print(args.terse, sep='', end='') + verbose = args.verbose interactive = args.interactive generateOnly = args.generate @@ -99,8 +106,9 @@ for i in range(1, 11): print("correctanswers[%d] = %s\n" % (i,ans)); else: - print("========== Executing Query {}".format(i)) - print(queries[i]) + if not terse: + print("========== Executing Query {}".format(i)) + print(queries[i]) cur.execute(queries[i]) ans = cur.fetchall() @@ -114,7 +122,10 @@ for i in range(1, 11): # Compare with correctanswers[i] cmp_res = compareAnswers(ans, correctanswers[i]) - print("-----> " + cmp_res[0]) + if terse: + print(",", cmp_res[1], sep='', end='') + else: + print("-----> " + cmp_res[0]) totalscore += cmp_res[1] if interactive: input('Press enter to proceed') @@ -123,5 +134,7 @@ for i in range(1, 11): print(sys.exc_info()) raise -if not generateOnly: +if terse: + print("", sep='') +elif not generateOnly: print("-----------------> Total Score = {}".format(totalscore)) diff --git a/project1/queries.py b/project1/queries.py index 88c961f..27f4008 100644 --- a/project1/queries.py +++ b/project1/queries.py @@ -12,7 +12,10 @@ order by city; ### 1. Write a query to find the names of the customers whose names are at least 15 characters long, and the second letter in the name is "l". ### Order by name. queries[1] = """ -select 0; +SELECT name +FROM customers +WHERE LENGTH(name) >= 15 AND name LIKE '_l%' +ORDER BY name; """ @@ -20,27 +23,71 @@ select 0; ### Order output by Customer Name. ### Output columns: all columns from customers queries[2] = """ -select 0; +WITH ids AS +(SELECT DISTINCT customers.customerid +FROM customers +INNER JOIN flewon ON customers.customerid = flewon.customerid +WHERE +EXTRACT(DAY FROM birthdate) = EXTRACT(DAY FROM flightdate) +AND +EXTRACT(MONTH FROM birthdate) = EXTRACT(MONTH FROM flightdate)) +SELECT * FROM customers +WHERE customerid IN (SELECT * FROM ids) +ORDER BY name; """ ### 3. Write a query to generate a list: (source_city, source_airport_code, dest_city, dest_airport_code, number_of_flights) for all source-dest pairs with at least 3 flights. ### Order first by number_of_flights in decreasing order, then source_city in the increasing order, and then dest_city in the increasing order. ### Note: You must generate the source and destination cities along with the airport codes. queries[3] = """ -select 0; +WITH source_airports AS +( +SELECT airportid AS source, city AS source_city FROM airports +), +dest_airports AS +( +SELECT airportid AS dest, city AS dest_city FROM airports +), +flight_counts AS +( +SELECT source_city, flights.source AS source_airport_code, dest_city, flights.dest AS dest_airport_code, COUNT(*) AS number_of_flights +FROM flights +INNER JOIN source_airports ON flights.source = source_airports.source +INNER JOIN dest_airports ON flights.dest = dest_airports.dest +GROUP BY source_city, flights.source, dest_city, flights.dest +) +SELECT * +FROM flight_counts +WHERE number_of_flights >= 3 +ORDER BY number_of_flights DESC, source_city ASC, dest_city ASC; """ ### 4. Find the name of the airline with the maximum number of customers registered as frequent fliers. ### Output only the name of the airline. If multiple answers, order by name. queries[4] = """ -select 0; +WITH frequent_fliers_counts AS +(SELECT frequentflieron AS airlineid, COUNT(*) AS count FROM customers GROUP BY frequentflieron) +SELECT name +FROM airlines +INNER JOIN frequent_fliers_counts ON airlines.airlineid = frequent_fliers_counts.airlineid +WHERE count = (SELECT MAX(count) FROM frequent_fliers_counts) +ORDER BY name; """ ### 5. For all flights from OAK to IAD, list the flight id, airline name, and the ### duration in hours and minutes. So the output will have 4 fields: flightid, airline name, ### hours, minutes. Order by flightid. queries[5] = """ -select 0; +WITH flights_with_times AS +( +SELECT flightid, airlineid, local_arrival_time - local_departing_time AS elapsed +FROM flights +WHERE source = 'OAK' AND dest = 'IAD' +) +SELECT flightid, name AS airline_name, EXTRACT(HOUR FROM elapsed) AS hours, EXTRACT(MINUTE FROM elapsed) AS minutes +FROM flights_with_times +INNER JOIN airlines ON flights_with_times.airlineid = airlines.airlineid +ORDER BY flightid; """ ### 6. Write a query to find empty flights (flight, flight date) on any date @@ -48,7 +95,14 @@ select 0; ### flights took off as scheduled, with or without passengers. Order by flight ### id in increasing order, and then by date in increasing order. queries[6] = """ -select 0; +WITH valid_dates AS +(SELECT DISTINCT flightdate FROM flewon), +all_flights AS +(SELECT flightid, flightdate FROM flights CROSS JOIN valid_dates) +SELECT flightid, flightdate +FROM all_flights +EXCEPT (SELECT DISTINCT flightid, flightdate FROM flewon) +ORDER BY flightid ASC, flightdate ASC; """ ### 7. Write a query to generate a list of customers who don't list Southwest as their frequent flier airline, but @@ -56,15 +110,45 @@ select 0; ### Output columns: customerid, customer_name ### Order by: customerid queries[7] = """ -select 0; +WITH flewon_airline AS +( +SELECT customerid, airlineid FROM flewon INNER JOIN flights ON flewon.flightid = flights.flightid +), +flewon_airline_count AS +( +SELECT customerid, airlineid, COUNT(*) AS num_flights FROM flewon_airline GROUP BY customerid, airlineid +), +max_flights AS +( +SELECT customerid, MAX(num_flights) AS most_flown FROM flewon_airline_count GROUP BY customerid +), +preferred_airline AS +( +SELECT flewon_airline_count.customerid, airlineid +FROM flewon_airline_count +INNER JOIN max_flights ON flewon_airline_count.customerid = max_flights.customerid +WHERE num_flights = most_flown +ORDER BY flewon_airline_count.customerid +) +SELECT preferred_airline.customerid, name AS customer_name +FROM preferred_airline +INNER JOIN customers ON preferred_airline.customerid = customers.customerid +WHERE airlineid = 'SW' AND frequentflieron != 'SW' +ORDER BY customerid; """ -### 8. Write a query to generate a list of those customers whose first and last flights are 5 days apart. +### 8. Write a query to generate a list of customers where the interval between first and last flight is 5 days. ### Order by the customer name. ### Output columns: name ### Order by: name queries[8] = """ -select 0; +WITH intervals AS +(SELECT customerid, MAX(flightdate) - MIN(flightdate) AS interval FROM flewon GROUP BY customerid) +SELECT name +FROM intervals +INNER JOIN customers ON intervals.customerid = customers.customerid +WHERE interval = 5 +ORDER BY name; """ @@ -73,7 +157,16 @@ select 0; ### Output columns: customerid, airlinename ### Order by: customerid, airlinename queries[9] = """ -select 0; +WITH never_flown_on AS +( +SELECT customerid, airlineid +FROM customers CROSS JOIN airlines +EXCEPT (SELECT DISTINCT customerid, airlineid FROM flewon INNER JOIN flights ON flewon.flightid = flights.flightid) +) +SELECT customerid, name AS airlinename +FROM never_flown_on +INNER JOIN airlines ON never_flown_on.airlineid = airlines.airlineid +ORDER BY customerid, airlinename; """ @@ -83,7 +176,18 @@ select 0; ### Output columns: name,coupon ### Order by: name,coupon queries[10] = """ -select 0; +WITH ids AS +(SELECT DISTINCT customers.customerid +FROM customers +INNER JOIN flewon ON customers.customerid = flewon.customerid +WHERE +EXTRACT(DAY FROM birthdate) = EXTRACT(DAY FROM flightdate) +AND +EXTRACT(MONTH FROM birthdate) = EXTRACT(MONTH FROM flightdate)) +SELECT name, SUBSTRING(name for 3) || EXTRACT(DAY FROM birthdate) AS coupon +FROM customers +WHERE customerid IN (SELECT * FROM ids) +ORDER BY name, coupon; """ -- GitLab