From 2a66f18652a0c7b43e89bbad9b0848f81c4abcf1 Mon Sep 17 00:00:00 2001 From: Kamran Ahmed Date: Tue, 31 Dec 2024 03:50:22 +0000 Subject: [PATCH] Add inner join details --- .../lessons/foreign-key-constraint.md | 60 ++++ .../lessons/joins-in-queries.md | 291 ++++++++++++++++-- 2 files changed, 324 insertions(+), 27 deletions(-) diff --git a/src/data/courses/sql-mastery/chapters/multi-table-queries/lessons/foreign-key-constraint.md b/src/data/courses/sql-mastery/chapters/multi-table-queries/lessons/foreign-key-constraint.md index 5f623a633..72bf6ab91 100644 --- a/src/data/courses/sql-mastery/chapters/multi-table-queries/lessons/foreign-key-constraint.md +++ b/src/data/courses/sql-mastery/chapters/multi-table-queries/lessons/foreign-key-constraint.md @@ -177,4 +177,64 @@ CREATE TABLE book_editions ( 4. **Maintain Data Consistency**: Always insert parent records before child records and remove child records before parent records. +## Types of Joins Using Foreign Keys + +When working with foreign key relationships, you can use different types of JOIN operations to combine data from related tables: + +### INNER JOIN + +Returns only the matching records from both tables: + +```sql +SELECT books.title, sales.quantity +FROM books +INNER JOIN sales ON books.id = sales.book_id; +``` + +### LEFT JOIN (LEFT OUTER JOIN) + +Returns all records from the left table and matching records from the right table: + +```sql +SELECT books.title, COALESCE(sales.quantity, 0) as quantity +FROM books +LEFT JOIN sales ON books.id = sales.book_id; +``` + +### RIGHT JOIN (RIGHT OUTER JOIN) + +Returns all records from the right table and matching records from the left table: + +```sql +SELECT authors.name, books.title +FROM books +RIGHT JOIN authors ON books.author_id = authors.id; +``` + +### FULL JOIN (FULL OUTER JOIN) + +Returns all records from both tables, matching where possible: + +```sql +SELECT books.title, reviews.rating +FROM books +FULL OUTER JOIN reviews ON books.id = reviews.book_id; +``` + +### Cross Join + +Returns the Cartesian product of both tables (every possible combination): + +```sql +SELECT books.title, categories.name +FROM books +CROSS JOIN categories; +``` + +> 💡 **Note**: The type of JOIN you choose depends on your specific needs: +> - Use INNER JOIN when you only want matching records +> - Use LEFT/RIGHT JOIN when you need all records from one table +> - Use FULL JOIN when you need all records from both tables +> - Use CROSS JOIN rarely, typically for generating combinations + In the next lesson, we'll learn how to query data across multiple tables using these relationships. diff --git a/src/data/courses/sql-mastery/chapters/multi-table-queries/lessons/joins-in-queries.md b/src/data/courses/sql-mastery/chapters/multi-table-queries/lessons/joins-in-queries.md index f3121354a..4d28cc772 100644 --- a/src/data/courses/sql-mastery/chapters/multi-table-queries/lessons/joins-in-queries.md +++ b/src/data/courses/sql-mastery/chapters/multi-table-queries/lessons/joins-in-queries.md @@ -20,13 +20,55 @@ setup: | VALUES (1, 'John Doe'), (2, 'Jane Smith'), (3, 'Alice Johnson'), - (4, 'Bob Brown'); + (4, 'Bob Brown'), + (5, 'Samantha Jay'), + (6, 'Nicola Bateman'); + INSERT INTO author_biography (id, author_id, biography) - VALUES (1, 4, 'Bob Brown\'s biography'), - (2, 3, 'Alice Johnson\'s biography'), - (3, 2, 'Jane Smith\'s biography'), - (4, 1, 'John Doe\'s biography'); + VALUES (1, 4, 'Bob Brown''s biography'), + (2, 3, 'Alice Johnson''s biography'), + (3, 2, 'Jane Smith''s biography'), + (4, 1, 'John Doe''s biography'); + + CREATE TABLE customer ( + id INT PRIMARY KEY, + name VARCHAR(255) + ); + + CREATE TABLE sale ( + id INT PRIMARY KEY, + customer_id INT, + book_id INT, + amount DECIMAL(10, 2), + created_at DATE + ); + + CREATE TABLE book ( + id INT PRIMARY KEY, + title VARCHAR(255), + category VARCHAR(255) + ); + + INSERT INTO customer (id, name) + VALUES (1, 'John Doe'), + (2, 'Jane Smith'), + (3, 'Will Scott'), + (4, 'Bob Green'); + + INSERT INTO sale (id, customer_id, book_id, amount, created_at) + VALUES (1, 1, 1, 10.99, '2024-12-30'), + (2, 1, 2, 25.98, '2024-12-10'), + (3, 2, 1, 32.97, '2024-12-31'), + (4, 1, 1, 34.11, '2024-12-11'), + (5, 3, 3, 14.66, '2024-12-08'), + (6, 2, 3, 36.22, '2024-12-07'); + + INSERT INTO book (id, title, category) + VALUES (1, 'Harry Potter', 'Fantasy'), + (2, 'Lord of the Rings', 'Fantasy'), + (3, 'Pride and Prejudice', 'Romance'), + (4, 'Wuthering Heights', 'Tragedy'); ``` --- @@ -113,31 +155,226 @@ JOIN author_biography ab ON a.id = ab.author_id; The result from this query will be the same as the previous query. +## Types of JOINs + +SQL provides several types of JOINs, each with its own behavior and use cases. Here is the list of most common types: + +- `INNER JOIN` +- `LEFT JOIN` (or `LEFT OUTER JOIN`) +- `RIGHT JOIN` (or `RIGHT OUTER JOIN`) +- `FULL JOIN` (or `FULL OUTER JOIN`) +- `CROSS JOIN` + +If you notice our queries so far, we have been simply using `JOIN` in our queries. This is actually an alias for `INNER JOIN`; if you don't specify the type of join, it will default to `INNER JOIN`. + +The actual syntax for a `JOIN` query is as follows: + +```sql +SELECT table1.column1, table2.column1, ... +FROM table1 +join_type JOIN table2 +ON join_conditions; +``` + +`join_type` can be one of the types of joins and `join_conditions` is the condition to join the mentioned tables. Let's go through each of the types to understand how they work. + +### INNER JOIN + +The `INNER JOIN` is the most commonly used type of join. It returns only the matching rows from both tables. Any rows that do not have a match in the other table are not included in the result. + +#### Example 1 - One-to-One Relationship + +Let's take an example to understand this better. We will use the same `author` and `author_biography` tables as before with following data. + +![author-biography-data](https://assets.roadmap.sh/guest/author-no-biography-x74fu.png) + +Now, if we run the following query: + +```sql +SELECT a.name, ab.biography +FROM author a +INNER JOIN author_biography ab ON a.id = ab.author_id; +``` + +The result from this query will be: + +| name | biography | +| ------------- | ------------------------- | +| Bob Brown | Bob Brown's biography | +| Alice Johnson | Alice Johnson's biography | +| Jane Smith | Jane Smith's biography | +| John Doe | John Doe's biography | + +Notice how the authors "Samantha Jay" and "Nicola Bateman" are not included in the result as they do not have a biography. + +> Note: `JOIN` is the alias for `INNER JOIN` in SQL. However you should always specify the type of join explicitly to make your queries more readable and maintainable. + +#### Example 2 - One-to-Many Relationship + +Let's take another example to make sure that we understand the `INNER JOIN` better. In our next example we will use the `customer` and `sale` table with following data. + +![](https://assets.roadmap.sh/guest/customer-sale-tqbjq.png) + +There is a one-to-many relationship between `customer` and `sale` tables i.e. a customer can have 0 or more sales. Let's say we want to get all the customers along with their sales. + +```sql +SELECT c.name, s.amount +FROM customer c +INNER JOIN sale s ON c.id = s.customer_id; +``` + +The result from this query will be: + +| name | amount | +| ------------- | ------ | +| John Doe | 10.99 | +| John Doe | 25.98 | +| Jane Smith | 32.97 | +| John Doe | 34.11 | +| Alice Johnson | 14.66 | +| Jane Smith | 36.22 | + +Notice how the customers "Will Scott" and "Bob Green" are not included in the result as they do not have any sales. Also notice how the customers "John Doe" and "Jane Smith" have two sales each so we get two rows for them in the result. + +#### Example 3 - Many-to-Many Relationship + +In this last example we will look at a many-to-many relationship. We will use the `customer`, `sale` and `book` table with following data. + +![](https://assets.roadmap.sh/guest/customer-book-sale-6n4n4.png) + +Let's say we want to get all the customers along with their sale amount and book title. In this case will need to have two `INNER JOIN` clauses to join the `customer`, `sale` table first and then join the `sale` table with the `book` table. + +Our query will look like this: + +```sql +SELECT c.name, s.amount, b.title, TO_CHAR(s.created_at, 'YYYY-MM-DD') AS sale_date +FROM customer c +INNER JOIN sale s ON c.id = s.customer_id +INNER JOIN book b ON s.book_id = b.id; +``` + +The result from this query will be: +| name | amount | title | sale_date | +| ---------- | ------ | ------------------- | ---------- | +| John Doe | 10.99 | Harry Potter | 2024-12-30 | +| John Doe | 25.98 | Lord of the Rings | 2024-12-10 | +| Jane Smith | 32.97 | Harry Potter | 2024-12-31 | +| John Doe | 34.11 | Harry Potter | 2024-12-11 | +| Will Scott | 14.66 | Pride and Prejudice | 2024-12-08 | +| Jane Smith | 36.22 | Pride and Prejudice | 2024-12-07 | -Let's take the same example our bookstore from our previous lesson. Among the tables we had in our bookstore, we had `customer` and `sale`. Here is some data we have in both tables respectively: +Here is how the query works: -| id | name | email | phone | -| --- | ------------- | ------------------------- | ---------- | -| 1 | John Doe | john.doe@example.com | 1234567890 | -| 2 | Jane Smith | jane.smith@example.com | 0987654321 | -| 3 | Alice Johnson | alice.johnson@example.com | 1122334455 | -| 4 | Bob Brown | bob.brown@example.com | 9988776655 | -| 5 | Charlie Davis | charlie.davis@example.com | 1231231230 | +**Step 1** `customer` and `sale` tables are joined by verifying the `ON` condition i.e. `c.id = s.customer_id`. -| id | customer_id | book_id | quantity | price | date | -| --- | ----------- | ------- | -------- | ------ | ---------- | -| 1 | 1 | 1 | 2 | 20.00 | 2024-01-01 | -| 2 | 2 | 2 | 3 | 45.00 | 2024-01-02 | -| 3 | 2 | 1 | 1 | 10.00 | 2024-02-03 | -| 4 | 1 | 1 | 1 | 10.00 | 2024-02-04 | -| 5 | 1 | 1 | 2 | 20.00 | 2024-02-05 | -| 6 | 5 | 3 | 1 | 30.00 | 2024-02-06 | -| 7 | 4 | 3 | 4 | 120.00 | 2024-02-07 | -| 8 | 3 | 4 | 1 | 25.00 | 2024-02-08 | -| 9 | 3 | 4 | 1 | 25.00 | 2024-02-09 | -| 10 | 5 | 4 | 2 | 50.00 | 2024-02-10 | +![](https://assets.roadmap.sh/guest/customer-join-sale-sd3u5.png) + +**Step 2** Intermediate result is created with data from both tables. + +![](https://assets.roadmap.sh/guest/customer-join-sale-result-su1jd.png) + +**Step 3** This intermediate result is then joined with the `book` table by verifying the `ON` condition i.e. `s.book_id = b.id`. + +![](https://assets.roadmap.sh/guest/customer-sale-book-sjovk.png) + +**Step 4** Intermediate result is created with data from all three tables. + +[![](https://assets.roadmap.sh/guest/data-from-all-tables-xwtw4.png)](https://assets.roadmap.sh/guest/data-from-all-tables-xwtw4.png) + +**Step 5** Columns are returned based on `SELECT` clause. + +![](https://assets.roadmap.sh/guest/many-to-many-result-tum5k.png) + +### LEFT JOIN + +The `LEFT JOIN` (or `LEFT OUTER JOIN`) returns all rows from the left table and matching rows from the right table. If no match is found, NULL values are returned for the right table's columns. + +```sql +SELECT a.name, ab.biography +FROM author a +LEFT JOIN author_biography ab ON a.id = ab.author_id; +``` + +![](https://assets.roadmap.sh/guest/left-join-venn-diagram-p9m3n.png) + +For example, if we had an author without a biography: + +```sql +INSERT INTO author (id, name) VALUES (5, 'Carol White'); + +SELECT a.name, ab.biography +FROM author a +LEFT JOIN author_biography ab ON a.id = ab.author_id; +``` + +Result: +| name | biography | +|---------------|---------------------------| +| John Doe | John Doe's biography | +| Jane Smith | Jane Smith's biography | +| Alice Johnson | Alice Johnson's biography | +| Bob Brown | Bob Brown's biography | +| Carol White | NULL | + +### RIGHT JOIN + +The `RIGHT JOIN` (or `RIGHT OUTER JOIN`) is similar to LEFT JOIN but returns all rows from the right table and matching rows from the left table. + +```sql +SELECT a.name, ab.biography +FROM author a +RIGHT JOIN author_biography ab ON a.id = ab.author_id; +``` + +![](https://assets.roadmap.sh/guest/right-join-venn-diagram-t7k4m.png) + +### FULL JOIN + +The `FULL JOIN` (or `FULL OUTER JOIN`) returns all rows from both tables. If there's no match, NULL values are returned for the table that doesn't have a matching row. + +```sql +SELECT a.name, ab.biography +FROM author a +FULL JOIN author_biography ab ON a.id = ab.author_id; +``` + +![](https://assets.roadmap.sh/guest/full-join-venn-diagram-h8n5p.png) + +> Note: Not all database systems support FULL JOIN (e.g., MySQL). In such cases, you can simulate it using a combination of LEFT JOIN and RIGHT JOIN with UNION. + +### CROSS JOIN + +A `CROSS JOIN` returns the Cartesian product of both tables (every row from the first table paired with every row from the second table). It doesn't require a join condition. + +```sql +SELECT a.name, ab.biography +FROM author a +CROSS JOIN author_biography ab; +``` + +This would result in 16 rows (4 authors × 4 biographies) where every author is paired with every biography, regardless of the author_id relationship. + +## Best Practices for Using JOINs + +1. **Always specify the join type explicitly** - While `JOIN` defaults to `INNER JOIN`, it's better to be explicit for code readability. + +2. **Use table aliases** - Especially when dealing with multiple joins, aliases make queries more readable and maintainable. + +3. **Qualify column names** - When columns exist in multiple tables, always qualify them with table names or aliases to avoid ambiguity. + +```sql +-- Good: Using aliases and qualified column names +SELECT a.name, ab.biography +FROM author a +INNER JOIN author_biography ab ON a.id = ab.author_id; + +-- Not as good: No aliases, unqualified columns +SELECT name, biography +FROM author +INNER JOIN author_biography ON id = author_id; +``` -Notice how the `sale` table has a `customer_id` column that references the `id` column in the `customer` table. This is a relationship between the two tables. +4. **Consider performance** - JOINs can be resource-intensive, especially with large tables. Only select the columns you need and ensure proper indexing on join columns. -We can use this relationship to query data from both tables. +Now that you understand different types of JOINs, you can choose the appropriate one based on your specific needs. In the next lesson, we'll explore more complex scenarios involving multiple JOINs.