Entering content frame

This graphic is explained in the accompanying text Joins: Information from Several Tables Locate the document in the library structure

In order to respond to some queries, the system must search several tables. The link between these tables is established on the basis of columns that appear in several tables. Statements such as this are called a “join.”

Prerequisites

You require the demo data for the SQL Tutorial.

Start the query tool SQL Studio as database administrator MONA with password RED and log on to the demo database instance DEMODB.

Examples

SELECT reservation.rno, customer.name, reservation.arrival, reservation.departure
  FROM hotel.customer, hotel.reservation
    WHERE customer.name = 'Porter'
      AND customer.cno = reservation.cno

Displaying whether and when a reservation was made for the customer “Porter”

Result

RNO

NAME

ARRIVAL

DEPARTURE

100

Porter

2004-11-13

2004-11-15

110

Porter

2004-12-24

2005-01-06

The link between the two tables is established on the basis of the customer number, that is, only those rows that contain the name “Porter” and in which the customer numbers are identical are selected. =, <, <=, >, >=, and <> are possible operators in the WHERE clause.

The overall result row comprises the desired columns in the relevant table. If columns in two different tables have the same name, the table name must be specified in the statement before the column name; the two names are then linked by a period (.).

 

SELECT customer.name, reservation.rno, hotel.name hotel_name
  FROM hotel.customer, hotel.reservation, hotel.hotel
    WHERE customer.name = 'Porter'
      AND customer.cno=reservation.cno
      AND reservation.hno = hotel.hno

Displaying all the hotels in which the customer “Porter” has made a reservation. For this purpose, the customer, reservation, and hotel tables must be concatenated.

Result

NAME

RNO

HOTEL_NAME

Porter

100

Midtown

Porter

110

Beach

 

Outer Join

First, here is another example of a join:

 

SELECT hotel.name hotel_name, city.zip, city.name city_name
  FROM hotel.hotel, hotel.city
    WHERE city.state = 'CA' AND city.zip=hotel.zip

Displaying the cities in the state of CA for which hotels are specified in the hotel table

Result

HOTEL_NAME

ZIP

CITY_NAME

Long Beach

90804

Long Beach

Star

90029

Hollywood

Indian Horse

92262

Palm Springs

 

If you now want to display all city names, regardless of whether or not a hotel is specified for these individual cities, you can use an outer join.

An outer join is represented by the operator (+).

 

SELECT hotel.name hotel_name, city.zip, city.name city_name
  FROM hotel.hotel, hotel.city
    WHERE city.state = 'CA' AND city.zip=hotel.zip (+)

Displaying the cities in the state of CA for which hotels are specified in the hotel table

Result

HOTEL_NAME

ZIP

CITY_NAME

Long Beach

90804

Long Beach

Star

90029

Hollywood

Indian Horse

92262

Palm Springs

?

90018

Los Angeles

?

92714

Irvine

?

95054

Santa Clara

A list of all the cities in the state of CA is displayed. For those cities for which no hotel entries exist, the system assigns the hotel name a NULL value.

 

See also:

SQL Reference Manual, Structure linkJOIN Predicate (join_predicate)

More examples for Data Query

 

Leaving content frame