where extract(month FROM birthdate) = extract(month FROM flightdate) and extract(day FROM birthdate) = extract(day FROM flightdate)
INNER JOIN flewon ON customers.customerid = flewon.customerid
order by name;
WHERE
"""
EXTRACT(DAY FROM birthdate) = EXTRACT(DAY FROM flightdate)
AND
### 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.
EXTRACT(MONTH FROM birthdate) = EXTRACT(MONTH FROM flightdate))
### Order first by number_of_flights in decreasing order, then source_city in the increasing order, and then dest_city in the increasing order.
SELECT * FROM customers
### Note: You must generate the source and destination cities along with the airport codes.
WHERE customerid IN (SELECT * FROM ids)
queries[3]="""
ORDER BY name;
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)
### 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 by a.source, a.dest),
### 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.
common_count (source, dest, count) as
queries[3]="""
(select source, dest, count(*)
WITH source_airports AS
from common_flights
(
group by source, dest
SELECT airportid AS source, city AS source_city FROM airports
having count(*) >= 3),
),
dest_airports AS
source_city (source_city, source_airport_code, dest_airport_code, number_of_flights) as
(
(select a.city as source_city, c.*
SELECT airportid AS dest, city AS dest_city FROM airports
from common_count c left join airports a
),
on c.source = a.airportid)
flight_counts AS
(
select s.source_city, s.source_airport_code, a.city as dest_city, s.dest_airport_code, s.number_of_flights
SELECT source_city, flights.source AS source_airport_code, dest_city, flights.dest AS dest_airport_code, COUNT(*) AS number_of_flights
from source_city s left join airports a
FROM flights
on s.dest_airport_code = a.airportid
INNER JOIN source_airports ON flights.source = source_airports.source
order by number_of_flights desc, source_city, dest_city;
INNER JOIN dest_airports ON flights.dest = dest_airports.dest
"""
GROUP BY source_city, flights.source, dest_city, flights.dest
)
### 4. Find the name of the airline with the maximum number of customers registered as frequent fliers.
SELECT *
### Output only the name of the airline. If multiple answers, order by name.
FROM flight_counts
queries[4]="""
WHERE number_of_flights >= 3
with counts (airlineid, ff_count) as (select frequentflieron, count(frequentflieron) as ff_count
ORDER BY number_of_flights DESC, source_city ASC, dest_city ASC;
from customers
"""
group by frequentflieron
order by frequentflieron),
### 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.
highest_ff (airlineid, ff_count) as (select airlineid, ff_count
queries[4]="""
from counts
WITH frequent_fliers_counts AS
where ff_count = (select max(ff_count) from counts))
(SELECT frequentflieron AS airlineid, COUNT(*) AS count FROM customers GROUP BY frequentflieron)
SELECT name
select name
FROM airlines
from highest_ff h join airlines a
INNER JOIN frequent_fliers_counts ON airlines.airlineid = frequent_fliers_counts.airlineid
on h.airlineid = a.airlineid
WHERE count = (SELECT MAX(count) FROM frequent_fliers_counts)
order by name;
ORDER BY name;
"""
"""
### 5. For all flights from OAK to IAD, list the flight id, airline name, and the
### 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,
### duration in hours and minutes. So the output will have 4 fields: flightid, airline name,
### hours, minutes. Order by flightid.
### hours, minutes. Order by flightid.
queries[5]="""
queries[5]="""
with oak_flights (flightid, airlineid, duration) as (select flightid, airlineid, (local_arrival_time - local_departing_time) as duration
WITH flights_with_times AS
from flights
(
where source = 'OAK' and dest = 'IAD')
SELECT flightid, airlineid, local_arrival_time - local_departing_time AS elapsed
FROM flights
select flightid, name, extract(hour FROM duration) as hours, extract(minute FROM duration) as minutes
WHERE source = 'OAK' AND dest = 'IAD'
from oak_flights o join airlines a
)
on o.airlineid = a.airlineid
SELECT flightid, name AS airline_name, EXTRACT(HOUR FROM elapsed) AS hours, EXTRACT(MINUTE FROM elapsed) AS minutes
order by flightid;
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
### 6. Write a query to find empty flights (flight, flight date) on any date
### id in increasing order, and then by date in increasing order.
### which someone flew. Assume that if anyone flew on a given date, all
queries[6]="""
### flights took off as scheduled, with or without passengers. Order by flight
with days_of_flights (flight_date) as (select distinct flightdate
### id in increasing order, and then by date in increasing order.
from flewon),
queries[6]="""
WITH valid_dates AS
cart_product (flightid, flight_date) as (select a.flightid, b.flight_date
(SELECT DISTINCT flightdate FROM flewon),
from flights a, days_of_flights b
all_flights AS
order by a.flightid, b.flight_date)
(SELECT flightid, flightdate FROM flights CROSS JOIN valid_dates)
SELECT flightid, flightdate
select *
FROM all_flights
from cart_product
EXCEPT (SELECT DISTINCT flightid, flightdate FROM flewon)
except (select distinct b.flightid, flightdate
ORDER BY flightid ASC, flightdate ASC;
from flights a, flewon b
"""
where a.flightid = b.flightid
order by b.flightid, flightdate)
### 7. Write a query to generate a list of customers who don't list Southwest as their frequent flier airline, but
order by flightid, flight_date;
### actually flew the most (by number of flights) on that airline.
"""
### Output columns: customerid, customer_name
### Order by: customerid
### 7. Write a query to generate a list of customers who don't list Southwest as their frequent flier airline, but
queries[7]="""
### actually flew the most (by number of flights) on that airline.
WITH flewon_airline AS
### Output columns: customerid, customer_name
(
### Order by: customerid
SELECT customerid, airlineid FROM flewon INNER JOIN flights ON flewon.flightid = flights.flightid
queries[7]="""
),
with counts (customerid, airlineid, frequency) as (select a.customerid, b.airlineid, count(b.airlineid) as frequency
flewon_airline_count AS
from flewon a left join flights b
(
on a.flightid = b.flightid
SELECT customerid, airlineid, COUNT(*) AS num_flights FROM flewon_airline GROUP BY customerid, airlineid
group by a.customerid, b.airlineid
),
order by a.customerid),
max_flights AS
(
maximums (customerid, max) as (select counts.customerid, max(counts.frequency)
SELECT customerid, MAX(num_flights) AS most_flown FROM flewon_airline_count GROUP BY customerid
from counts
),
group by counts.customerid
preferred_airline AS
order by counts.customerid),
(
SELECT flewon_airline_count.customerid, airlineid
max_airlines (customerid, airlineid) as (select a.customerid, a.airlineid, b.max
FROM flewon_airline_count
from counts a join maximums b
INNER JOIN max_flights ON flewon_airline_count.customerid = max_flights.customerid
on a.customerid = b.customerid
WHERE num_flights = most_flown
where a.frequency = b.max)
ORDER BY flewon_airline_count.customerid
)
select a.customerid, b.name as customer_name
SELECT preferred_airline.customerid, name AS customer_name
from max_airlines a left join customers b
FROM preferred_airline
on a.customerid = b.customerid
INNER JOIN customers ON preferred_airline.customerid = customers.customerid
where b.frequentflieron != 'SW' and a.airlineid = 'SW'
WHERE airlineid = 'SW' AND frequentflieron != 'SW'
order by customerid;
ORDER BY customerid;
"""
"""
### 8. Write a query to generate a list of customers where the interval between first and last flight is 5 days.
### 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.
### Order by the customer name.
### Output columns: name
### Output columns: name
### Order by: name
### Order by: name
queries[8]="""
queries[8]="""
with first_last (customerid, interval) as (select customerid, (extract(day FROM max(flightdate)) - extract(day FROM min(flightdate))) as interval
WITH intervals AS
from flewon
(SELECT customerid, MAX(flightdate) - MIN(flightdate) AS interval FROM flewon GROUP BY customerid)
group by customerid
SELECT name
having extract(month FROM max(flightdate)) = extract(month FROM min(flightdate))
FROM intervals
and extract(year FROM max(flightdate)) = extract(year FROM min(flightdate)))
INNER JOIN customers ON intervals.customerid = customers.customerid
WHERE interval = 5
select b.name
ORDER BY 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
### 9. For each customer, find the airlines on which they have never
queries[9]="""
### flown. One output row per customer/airline-name pair.
WITH never_flown_on AS
### Output columns: customerid, airlinename
(
### Order by: customerid, airlinename
SELECT customerid, airlineid
queries[9]="""
FROM customers CROSS JOIN airlines
with never_flown as ((select customerid, a.airlineid
EXCEPT (SELECT DISTINCT customerid, airlineid FROM flewon INNER JOIN flights ON flewon.flightid = flights.flightid)
from customers c, airlines a
)
order by c.customerid)
SELECT customerid, name AS airlinename
FROM never_flown_on
except
INNER JOIN airlines ON never_flown_on.airlineid = airlines.airlineid
ORDER BY customerid, airlinename;
(select a.customerid, b.airlineid
"""
from flewon a left join flights b
on a.flightid = b.flightid
group by a.customerid, b.airlineid
### 10. For each customer who flew on his/her own birthday, generate a
order by a.customerid))
### "coupon code" string consisting of the first three characters of
### their name concatenated with the day-of-the-month of their birthday.
select a.customerid, b.name as airlinename
### Output columns: name,coupon
from never_flown a left join airlines b
### Order by: name,coupon
on a.airlineid = b.airlineid
queries[10]="""
order by a.customerid, b.name;
WITH ids AS
"""
(SELECT DISTINCT customers.customerid
FROM customers
INNER JOIN flewon ON customers.customerid = flewon.customerid
### 10. For each customer who flew on his/her own birthday, generate a
WHERE
### "coupon code" string consisting of the first three characters of
EXTRACT(DAY FROM birthdate) = EXTRACT(DAY FROM flightdate)
### their name concatenated with the day-of-the-month of their birthday.
AND
### Output columns: name,coupon
EXTRACT(MONTH FROM birthdate) = EXTRACT(MONTH FROM flightdate))
### Order by: name,coupon
SELECT name, SUBSTRING(name for 3) || EXTRACT(DAY FROM birthdate) AS coupon
queries[10]="""
FROM customers
select name, concat(substring(name, 1, 3),extract(day FROM birthdate)) as coupon
WHERE customerid IN (SELECT * FROM ids)
from customers a left join flewon b
ORDER BY name, coupon;
on a.customerid = b.customerid
"""
where
(extract(month FROM birthdate) = extract(month FROM flightdate)) and
(extract(day FROM birthdate) = extract(day FROM flightdate))