Click here to Skip to main content
15,860,859 members
Articles / Database Development / SQL Server / SQL Server 2008

Visual Representation of SQL Joins

Rate me:
Please Sign up or sign in to vote.
4.96/5 (457 votes)
3 Feb 2009CPOL3 min read 3.5M   13.9K   570   149
This article describes SQL Joins in a visual manner, and also the most efficient way to write the visualized Joins.
This is just a simple article visually explaining SQL JOINs. In this article I am going to discuss seven different ways you can return data from two relational tables. The seven Joins I will discuss are: Inner JOIN, Left JOIN, Right JOIN, Outer JOIN, Left Excluding JOIN, Right Excluding JOIN, Outer Excluding JOIN, while providing examples of each.

Background

I'm a pretty visual person. Things seem to make more sense as a picture. I looked all over the Internet for a good graphical representation of SQL JOINs, but I couldn't find any to my liking. Some had good diagrams but lacked completeness (they didn't have all the possible JOINs), and some were just plain terrible. So, I decided to create my own and write an article about it.

Using the code

I am going to discuss seven different ways you can return data from two relational tables. I will be excluding cross Joins and self referencing Joins. The seven Joins I will discuss are shown below:

  1. INNER JOIN
  2. LEFT JOIN
  3. RIGHT JOIN
  4. OUTER JOIN
  5. LEFT JOIN EXCLUDING INNER JOIN
  6. RIGHT JOIN EXCLUDING INNER JOIN
  7. OUTER JOIN EXCLUDING INNER JOIN

For the sake of this article, I'll refer to 5, 6, and 7 as LEFT EXCLUDING JOIN, RIGHT EXCLUDING JOIN, and OUTER EXCLUDING JOIN, respectively. Some may argue that 5, 6, and 7 are not really joining the two tables, but for simplicity, I will still refer to these as Joins because you use a SQL Join in each of these queries (but exclude some records with a WHERE clause).

Inner JOIN

Visual_SQL_Joins/INNER_JOIN.png

This is the simplest, most understood Join and is the most common. This query will return all of the records in the left table (table A) that have a matching record in the right table (table B). This Join is written as follows:

SQL
SELECT <select_list> 
FROM Table_A A
INNER JOIN Table_B B
ON A.Key = B.Key

Left JOIN

Visual_SQL_Joins/LEFT_JOIN.png

This query will return all of the records in the left table (table A) regardless if any of those records have a match in the right table (table B). It will also return any matching records from the right table. This Join is written as follows:

SQL
SELECT <select_list>
FROM Table_A A
LEFT JOIN Table_B B
ON A.Key = B.Key

Right JOIN

Visual_SQL_Joins/RIGHT_JOIN.png

This query will return all of the records in the right table (table B) regardless if any of those records have a match in the left table (table A). It will also return any matching records from the left table. This Join is written as follows:

SQL
SELECT <select_list>
FROM Table_A A
RIGHT JOIN Table_B B
ON A.Key = B.Key

Outer JOIN

Visual_SQL_Joins/FULL_OUTER_JOIN.png

This Join can also be referred to as a FULL OUTER JOIN or a FULL JOIN. This query will return all of the records from both tables, joining records from the left table (table A) that match records from the right table (table B). This Join is written as follows:

SQL
SELECT <select_list>
FROM Table_A A
FULL OUTER JOIN Table_B B
ON A.Key = B.Key

Left Excluding JOIN

Visual_SQL_Joins/LEFT_EXCLUDING_JOIN.png

This query will return all of the records in the left table (table A) that do not match any records in the right table (table B). This Join is written as follows:

SQL
SELECT <select_list> 
FROM Table_A A
LEFT JOIN Table_B B
ON A.Key = B.Key
WHERE B.Key IS NULL

Right Excluding JOIN

Visual_SQL_Joins/RIGHT_EXCLUDING_JOIN.png

This query will return all of the records in the right table (table B) that do not match any records in the left table (table A). This Join is written as follows:

SQL
SELECT <select_list>
FROM Table_A A
RIGHT JOIN Table_B B
ON A.Key = B.Key
WHERE A.Key IS NULL

Outer Excluding JOIN

Visual_SQL_Joins/OUTER_EXCLUDING_JOIN.png

This query will return all of the records in the left table (table A) and all of the records in the right table (table B) that do not match. I have yet to have a need for using this type of Join, but all of the others, I use quite frequently. This Join is written as follows:

SQL
SELECT <select_list>
FROM Table_A A
FULL OUTER JOIN Table_B B
ON A.Key = B.Key
WHERE A.Key IS NULL OR B.Key IS NULL

Examples

Suppose we have two tables, Table_A and Table_B. The data in these tables are shown below:

TABLE_A
  PK Value
---- ----------
   1 FOX
   2 COP
   3 TAXI
   6 WASHINGTON
   7 DELL
   5 ARIZONA
   4 LINCOLN
  10 LUCENT

TABLE_B
  PK Value
---- ----------
   1 TROT
   2 CAR
   3 CAB
   6 MONUMENT
   7 PC
   8 MICROSOFT
   9 APPLE
  11 SCOTCH

The results of the seven Joins are shown below:

-- INNER JOIN
SELECT A.PK AS A_PK, A.Value AS A_Value,
       B.Value AS B_Value, B.PK AS B_PK
FROM Table_A A
INNER JOIN Table_B B
ON A.PK = B.PK

A_PK A_Value    B_Value    B_PK
---- ---------- ---------- ----
   1 FOX        TROT          1
   2 COP        CAR           2
   3 TAXI       CAB           3
   6 WASHINGTON MONUMENT      6
   7 DELL       PC            7

(5 row(s) affected)
-- LEFT JOIN
SELECT A.PK AS A_PK, A.Value AS A_Value,
B.Value AS B_Value, B.PK AS B_PK
FROM Table_A A
LEFT JOIN Table_B B
ON A.PK = B.PK

A_PK A_Value    B_Value    B_PK
---- ---------- ---------- ----
   1 FOX        TROT          1
   2 COP        CAR           2
   3 TAXI       CAB           3
   4 LINCOLN    NULL       NULL
   5 ARIZONA    NULL       NULL
   6 WASHINGTON MONUMENT      6
   7 DELL       PC            7
  10 LUCENT     NULL       NULL

(8 row(s) affected)
-- RIGHT JOIN
SELECT A.PK AS A_PK, A.Value AS A_Value,
B.Value AS B_Value, B.PK AS B_PK
FROM Table_A A
RIGHT JOIN Table_B B
ON A.PK = B.PK

A_PK A_Value    B_Value    B_PK
---- ---------- ---------- ----
   1 FOX        TROT          1
   2 COP        CAR           2
   3 TAXI       CAB           3
   6 WASHINGTON MONUMENT      6
   7 DELL       PC            7
NULL NULL       MICROSOFT     8
NULL NULL       APPLE         9
NULL NULL       SCOTCH       11

(8 row(s) affected)
-- OUTER JOIN
SELECT A.PK AS A_PK, A.Value AS A_Value,
B.Value AS B_Value, B.PK AS B_PK
FROM Table_A A
FULL OUTER JOIN Table_B B
ON A.PK = B.PK

A_PK A_Value    B_Value    B_PK
---- ---------- ---------- ----
   1 FOX        TROT          1
   2 COP        CAR           2
   3 TAXI       CAB           3
   6 WASHINGTON MONUMENT      6
   7 DELL       PC            7
NULL NULL       MICROSOFT     8
NULL NULL       APPLE         9
NULL NULL       SCOTCH       11
   5 ARIZONA    NULL       NULL
   4 LINCOLN    NULL       NULL
  10 LUCENT     NULL       NULL

(11 row(s) affected)
-- LEFT EXCLUDING JOIN
SELECT A.PK AS A_PK, A.Value AS A_Value,
B.Value AS B_Value, B.PK AS B_PK
FROM Table_A A
LEFT JOIN Table_B B
ON A.PK = B.PK
WHERE B.PK IS NULL

A_PK A_Value    B_Value    B_PK
---- ---------- ---------- ----
   4 LINCOLN    NULL       NULL
   5 ARIZONA    NULL       NULL
  10 LUCENT     NULL       NULL
(3 row(s) affected)
-- RIGHT EXCLUDING JOIN
SELECT A.PK AS A_PK, A.Value AS A_Value,
B.Value AS B_Value, B.PK AS B_PK
FROM Table_A A
RIGHT JOIN Table_B B
ON A.PK = B.PK
WHERE A.PK IS NULL

A_PK A_Value    B_Value    B_PK
---- ---------- ---------- ----
NULL NULL       MICROSOFT     8
NULL NULL       APPLE         9
NULL NULL       SCOTCH       11

(3 row(s) affected)
-- OUTER EXCLUDING JOIN
SELECT A.PK AS A_PK, A.Value AS A_Value,
B.Value AS B_Value, B.PK AS B_PK
FROM Table_A A
FULL OUTER JOIN Table_B B
ON A.PK = B.PK
WHERE A.PK IS NULL
OR B.PK IS NULL

A_PK A_Value    B_Value    B_PK
---- ---------- ---------- ----
NULL NULL       MICROSOFT     8
NULL NULL       APPLE         9
NULL NULL       SCOTCH       11
   5 ARIZONA    NULL       NULL
   4 LINCOLN    NULL       NULL
  10 LUCENT     NULL       NULL

(6 row(s) affected)

Note on the OUTER JOIN that the inner joined records are returned first, followed by the right joined records, and then finally the left joined records (at least, that's how my Microsoft SQL Server did it; this, of course, is without using any ORDER BY statement).

You can visit the Wikipedia article for more info here (however, the entry is not graphical).

I've also created a cheat sheet that you can print out if needed. If you right click on the image below and select "Save Target As...", you will download the full size image.

Image 8

History

  • Initial release -- 02/03/2009.
  • Version 1.0 -- 02/04/2009 -- Fixed cheat sheet and minor typos.

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)


Written By
Green Sand Software
United States United States
This member has not yet provided a Biography. Assume it's interesting and varied, and probably something to do with programming.

Comments and Discussions

 
QuestionOuter Excluding JOIN - I just needed this Pin
GuyThiebaut26-Jan-14 23:10
professionalGuyThiebaut26-Jan-14 23:10 
GeneralMy vote of 5 Pin
mielniczuk20-Jan-14 7:53
mielniczuk20-Jan-14 7:53 
QuestionNice Explanation :-) Easily understood the concepts Pin
rajas24066-Jan-14 19:54
rajas24066-Jan-14 19:54 
QuestionMessage Removed Pin
16-Oct-13 14:55
Member 127809916-Oct-13 14:55 
QuestionMaybe not a JOIN question... Pin
AlexEvans26-Sep-13 0:01
AlexEvans26-Sep-13 0:01 
QuestionVote of 5 Pin
TrollTier23-Sep-13 4:08
TrollTier23-Sep-13 4:08 
QuestionHow is join different from regular select ~ where ~ ? Pin
Member 102627609-Sep-13 9:32
Member 102627609-Sep-13 9:32 
AnswerRe: How is join different from regular select ~ where ~ ? Pin
C.L. Moffatt10-Sep-13 8:15
C.L. Moffatt10-Sep-13 8:15 
GeneralMy vote of 5 Pin
colin harris16-Aug-13 0:48
colin harris16-Aug-13 0:48 
GeneralMy vote of 5 Pin
Tilmiz22-Jul-13 16:55
Tilmiz22-Jul-13 16:55 
GeneralMy Vote of 5 Pin
Anoop Kr Sharma22-Jul-13 16:14
professionalAnoop Kr Sharma22-Jul-13 16:14 
QuestionJOINS Pin
Newbies100211-Jun-13 10:16
Newbies100211-Jun-13 10:16 
GeneralMy vote of 5 Pin
Arlen Navasartian30-May-13 5:10
Arlen Navasartian30-May-13 5:10 
GeneralMy vote of 5 Pin
Maciej Los5-Apr-13 2:39
mveMaciej Los5-Apr-13 2:39 
GeneralMy vote of 5 Pin
cycnus31-Mar-13 14:53
cycnus31-Mar-13 14:53 
Questionthank u Pin
Amra Rama12-Mar-13 5:22
Amra Rama12-Mar-13 5:22 
GeneralMy vote of 5 Pin
Chathura Roshan22-Jan-13 22:15
Chathura Roshan22-Jan-13 22:15 
GeneralMy vote of 5 Pin
AndrehPoffo23-Nov-12 5:59
AndrehPoffo23-Nov-12 5:59 
QuestionJOIN Pin
mitu sinha13-Nov-12 21:59
mitu sinha13-Nov-12 21:59 
AnswerRe: JOIN Pin
C.L. Moffatt14-Nov-12 4:04
C.L. Moffatt14-Nov-12 4:04 
QuestionLeft Join Pin
mah22446-Nov-12 2:59
mah22446-Nov-12 2:59 
AnswerRe: Left Join Pin
C.L. Moffatt14-Nov-12 3:59
C.L. Moffatt14-Nov-12 3:59 
GeneralMy vote of 5 Pin
kamalsamant25-Oct-12 21:37
kamalsamant25-Oct-12 21:37 
GeneralMy vote of 5 Pin
Farhan Ghumra21-Sep-12 0:14
professionalFarhan Ghumra21-Sep-12 0:14 
GeneralMy vote of 5 Pin
wrecklass9-Sep-12 13:21
wrecklass9-Sep-12 13:21 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Praise Praise    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.