### 0. List all airport codes and their cities. Order by the city name in the increasing order.
### Output column order: airportid, city
queries[0]="""
select airportid, city
from airports
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 name
FROM customers
WHERE LENGTH(name) >= 15 AND name LIKE '_l%'
ORDER BY name;
"""
### 2. Write a query to find any customers who flew on their birthday. Hint: Use "extract" function that operates on the dates.
### Order output by Customer Name.
### Output columns: all columns from customers
queries[2]="""
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]="""
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]="""
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]="""
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
### which someone flew. Assume that if anyone flew on a given date, all
### 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]="""
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
### actually flew the most (by number of flights) on that airline.
### Output columns: customerid, customer_name
### Order by: customerid
queries[7]="""
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 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]="""
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;
"""
### 9. For each customer, find the airlines on which they have never
### flown. One output row per customer/airline-name pair.
### Output columns: customerid, airlinename
### Order by: customerid, airlinename
queries[9]="""
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;
"""
### 10. For each customer who flew on his/her own birthday, generate a
### "coupon code" string consisting of the first three characters of
### their name concatenated with the day-of-the-month of their birthday.
### Output columns: name,coupon
### Order by: name,coupon
queries[10]="""
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;
"""
queries=[""foriinrange(0,12)]
### 0. List all airport codes and their cities. Order by the city name in the increasing order.
### Output column order: airportid, city
queries[0]="""
select airportid, city
from airports
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 name
from customers
where name like '_l%' and char_length(name) >= 15
order by name;
"""
### 2. Write a query to find any customers who flew on their birthday. Hint: Use "extract" function that operates on the dates.
where extract(month FROM birthdate) = extract(month FROM flightdate) and extract(day FROM birthdate) = extract(day FROM flightdate)
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]="""
with common_flights (flightid, source, dest, airlineid) as (select distinct a.flightid, a.source, a.dest, a.airlineid
from flights a, flights b
where (a.source = b.source) and (a.dest = b.dest) and (a.flightid != b.flightid)
order by a.source, a.dest),
common_count (source, dest, count) as
(select source, dest, count(*)
from common_flights
group by source, dest
having count(*) >= 3),
source_city (source_city, source_airport_code, dest_airport_code, number_of_flights) as
(select a.city as source_city, c.*
from common_count c left join airports a
on c.source = a.airportid)
select s.source_city, s.source_airport_code, a.city as dest_city, s.dest_airport_code, s.number_of_flights
from source_city s left join airports a
on s.dest_airport_code = a.airportid
order by number_of_flights desc, source_city, dest_city;
"""
### 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]="""
with counts (airlineid, ff_count) as (select frequentflieron, count(frequentflieron) as ff_count
from customers
group by frequentflieron
order by frequentflieron),
highest_ff (airlineid, ff_count) as (select airlineid, ff_count
from counts
where ff_count = (select max(ff_count) from counts))
select name
from highest_ff h join airlines a
on h.airlineid = a.airlineid
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]="""
with oak_flights (flightid, airlineid, duration) as (select flightid, airlineid, (local_arrival_time - local_departing_time) as duration
from flights
where source = 'OAK' and dest = 'IAD')
select flightid, name, extract(hour FROM duration) as hours, extract(minute FROM duration) as minutes
from oak_flights o join airlines a
on o.airlineid = a.airlineid
order by flightid;
"""
### 6. Write a query to find empty flights (flight, flight date) on any date
### which someone flew. Assume that if anyone flew on a given date, all
### 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]="""
with days_of_flights (flight_date) as (select distinct flightdate
from flewon),
cart_product (flightid, flight_date) as (select a.flightid, b.flight_date
from flights a, days_of_flights b
order by a.flightid, b.flight_date)
select *
from cart_product
except (select distinct b.flightid, flightdate
from flights a, flewon b
where a.flightid = b.flightid
order by b.flightid, flightdate)
order by flightid, flight_date;
"""
### 7. Write a query to generate a list of customers who don't list Southwest as their frequent flier airline, but
### actually flew the most (by number of flights) on that airline.
### Output columns: customerid, customer_name
### Order by: customerid
queries[7]="""
with counts (customerid, airlineid, frequency) as (select a.customerid, b.airlineid, count(b.airlineid) as frequency
from flewon a left join flights b
on a.flightid = b.flightid
group by a.customerid, b.airlineid
order by a.customerid),
maximums (customerid, max) as (select counts.customerid, max(counts.frequency)
from counts
group by counts.customerid
order by counts.customerid),
max_airlines (customerid, airlineid) as (select a.customerid, a.airlineid, b.max
from counts a join maximums b
on a.customerid = b.customerid
where a.frequency = b.max)
select a.customerid, b.name as customer_name
from max_airlines a left join customers b
on a.customerid = b.customerid
where b.frequentflieron != 'SW' and a.airlineid = 'SW'
order by customerid;
"""
### 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]="""
with first_last (customerid, interval) as (select customerid, (extract(day FROM max(flightdate)) - extract(day FROM min(flightdate))) as interval
from flewon
group by customerid
having extract(month FROM max(flightdate)) = extract(month FROM min(flightdate))
and extract(year FROM max(flightdate)) = extract(year FROM min(flightdate)))
select b.name
from first_last a left join customers b
on a.customerid = b.customerid
where interval = 5
order by b.name;
"""
### 9. For each customer, find the airlines on which they have never
### flown. One output row per customer/airline-name pair.
### Output columns: customerid, airlinename
### Order by: customerid, airlinename
queries[9]="""
with never_flown as ((select customerid, a.airlineid
from customers c, airlines a
order by c.customerid)
except
(select a.customerid, b.airlineid
from flewon a left join flights b
on a.flightid = b.flightid
group by a.customerid, b.airlineid
order by a.customerid))
select a.customerid, b.name as airlinename
from never_flown a left join airlines b
on a.airlineid = b.airlineid
order by a.customerid, b.name;
"""
### 10. For each customer who flew on his/her own birthday, generate a
### "coupon code" string consisting of the first three characters of
### their name concatenated with the day-of-the-month of their birthday.
### Output columns: name,coupon
### Order by: name,coupon
queries[10]="""
select name, concat(substring(name, 1, 3),extract(day FROM birthdate)) as coupon
from customers a left join flewon b
on a.customerid = b.customerid
where
(extract(month FROM birthdate) = extract(month FROM flightdate)) and
(extract(day FROM birthdate) = extract(day FROM flightdate))