Coding ON Clauses for Outer Joins - Teradata Database

SQL Data Manipulation Language

Product
Teradata Database
Release Number
15.00
Language
English (United States)
Last Update
2018-09-28
dita:id
B035-1146
lifecycle
previous
Product Category
Teradata® Database

Coding ON Clauses for Outer Joins

Introduction

Different join conditions in a FROM clause can yield very different results.

For example, suppose you wish to find out, using the three tables courses, offerings, and enrollment, whether the current course offerings satisfy the employee requests for courses, including the following information in the query.

  • Courses offered
  • Course locations
  • Courses requested but not offered
  • Employees who requested courses
  • Example  

    In the SELECT statement that follows, the offerings table is full outer joined to the enrollment table according to the first ON condition (offerings.course_no = enrollment.course_no).

         SELECT courses.course_no, offerings.course_no, offerings.location,
                enrollment.course_no, enrollment.emp_no
         FROM offerings
         FULL OUTER JOIN enrollment ON offerings.course_no =
                         enrollment.course_no 
         RIGHT OUTER JOIN courses ON courses.course_no =
                          offerings.course_no;

    The result of this intermediate join is shown in the following table:

     

    Note that BTEQ reports represent nulls with the QUESTION MARK character.

    This intermediate derived table is next right outer joined to the courses table, according to the second join condition (courses.course_no = offerings.course_no).

    The final results appear in the following table:

     

    Example  

    If the same SELECT statement is written with a different second join condition, as illustrated in the current example, then the offerings table is full outer joined to the enrollment table, according to the first JOIN condition (offerings.course_no = enrollment.course_no).

         SELECT courses.course_no, offerings.course_no,
                enrollment.course_no, enrollment.emp_no
         FROM offerings 
         FULL OUTER JOIN enrollment ON offerings.course_no =
                          enrollment.course_no 
         RIGHT OUTER JOIN courses ON courses.course_no =
                          enrollment.course_no;

    The result of this intermediate join is shown in the following table:

     

    Note that BTEQ reports represent nulls with the QUESTION MARK character.

    This intermediate derived table is next right outer joined to the courses table, according to the second join condition (courses.course_no = enrollment.course_no).

    The final results appear in the following table:

     

    Comparing the ON Clause Join Conditions of Examples 1 and 2

    Although the following second join conditions might intuitively appear to be equivalent, the results of a SELECT are different using the two different join conditions.

     

    Join Condition

    Example

    courses.course_no = offerings.course_no

    “Example 1” on page 274

    courses.course_no = enrollment.course_no

    “Example 2” on page 275

    Thus, using courses.course_no=offerings.course_no as the second join condition, you do not see in the results of the outer join, for example, that employee 236 registered for course C300.

    But if you use courses.course_no=enrollment.course_no as the second join condition, you do not see in the results of the outer join, for example, that courses C200 and C400 are, in fact, offered.

    For More Information

    For information on using WHERE clauses with ON clauses, see “Coding ON Clauses With WHERE Clauses for Outer Joins” on page 277.

    For guidelines on using ON and WHERE clauses with outer joins, see “Rules for Coding ON and WHERE Clauses for Outer Joins” on page 280.