Ask the Expert

Finding flights without regard to number of stops

We have a Flights table:

Flights(flight#,from,to)
Its data may include:
('A1','Washington','Paris')
Flight A1 from Washington to Paris

('A2','Toronto','London')
('A2','London','Dubai')
Flight A2 from Toronto to Dubai with
a stop in London

('A3','Toronto','Paris')
('A3','Paris','Dubai')
('A3','Dubai','Tehran')
Flight A3 from Toronto to Tehran
with stops in Paris and Dubai.
We may have multiple stops. The question is:
Write

    Requires Free Membership to View

a query that gets from (departure) and to (destination) cities and lists all flight numbers that travel from destination to departures without regard to number of stops during flight. For example for from='Toronto' and to='Tehran' give 'A3.' We are also permitted to use DB2 SQL extension if required.


I believe the key to this problem is knowing that the origin of a particular flight will be the only city at which no legs of that flight will arrive. On the same token, the final destination of a flight will be a city from which no legs depart. If these conditions were not the case, it would be in a situation such as one where a flight might loop back to the city of its origin. In this case, more information would be required in order to determine which city was the origin. For this example, we will assume the aforementioned conditions, that is, that flights will not loop back to their origins. Here is our table with its data:

create table FlightLegs
( FlightID char(2),
  FromCity varchar(15),
  ToCity varchar(15)
);

insert into FlightLegs values ('A1','Washington','Paris');
insert into FlightLegs values ('A2','Toronto','London');
insert into FlightLegs values ('A2','London','Dubai');
insert into FlightLegs values ('A3','Toronto','Paris');
insert into FlightLegs values ('A3','Paris','Dubai');
insert into FlightLegs values ('A3','Dubai','Tehran');
We can easily find the origin cities for the flights by selecting all those legs where the FromCity is not found as a ToCity in another leg. The SQL looks like this:
select f.FlightID, f.FromCity
  from FlightLegs f
  where not exists ( select * from FlightLegs 
                       where FlightID = f.FlightID 
                         and ToCity = f.FromCity );
This can be extended to find the final destinations for the flights by selecting all those legs where the ToCity is not found as a FromCity in any other legs. By using a self-join to combine these two conditions together, we get our solution:
select f.FlightID, f.FromCity Origin, t.ToCity FinalDest
  from FlightLegs f, FlightLegs t
  where f.FlightID = t.FlightID
    and not exists ( select * from FlightLegs 
                       where FlightID = f.FlightID 
                         and ToCity = f.FromCity )
    and not exists ( select * from FlightLegs 
                       where FlightID = t.FlightID 
                         and FromCity = t.ToCity );
Here are the resulting rows from this SQL:
FLIGHTID ORIGIN          FINALDEST
-------- --------------- ---------------
A1       Washington      Paris
A2       Toronto         Dubai
A3       Toronto         Tehran

For More Information

  • What do you think about this answer? E-mail the edtiors at editor@searchDatabase.com with your feedback.
  • The Best SQL Web Links: tips, tutorials, scripts, and more.
  • Have an SQL tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize. Submit your tip today!
  • Ask your technical SQL questions -- or help out your peers by answering them -- in our live discussion forums.
  • Ask the Experts yourself: Our SQL, database design, Oracle, SQL Server, DB2, metadata, object-oriented and data warehousing gurus are waiting to answer your toughest questions.

This was first published in March 2002

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to: