diff --git a/src/data/courses/sql-mastery/chapters/scalar-functions/lessons/book-sale-categories.md b/src/data/courses/sql-mastery/chapters/scalar-functions/lessons/book-sale-categories.md new file mode 100644 index 000000000..b9a1164bd --- /dev/null +++ b/src/data/courses/sql-mastery/chapters/scalar-functions/lessons/book-sale-categories.md @@ -0,0 +1,99 @@ +--- +title: Book Categories +description: Practice using CASE expressions to categorize books and inventory levels +order: 220 +type: challenge +setup: | + ```sql + CREATE TABLE book ( + id INT PRIMARY KEY, + title VARCHAR(100), + page_count INT, + publish_year INT, + copies_in_stock INT, + monthly_rentals INT + ); + + INSERT INTO book (id, title, page_count, publish_year, copies_in_stock, monthly_rentals) VALUES + (1, 'SQL Basics', 250, 2020, 5, 12), + (2, 'Advanced Queries', 450, 2021, 3, 8), + (3, 'Database Design', 350, 2019, 10, 15), + (4, 'Query Optimization', 275, 2022, 2, 6), + (5, 'Data Modeling', 400, 2021, 1, 4), + (6, 'PostgreSQL Tips', 200, 2023, 8, 20); + ``` +--- + +A library needs to analyze their SQL book collection. They want a report that categorizes books based on various criteria. + +Given the following data in table `book`: + +| id | title | page_count | publish_year | copies_in_stock | monthly_rentals | +| --- | ------------------ | ---------- | ------------ | --------------- | --------------- | +| 1 | SQL Basics | 250 | 2020 | 5 | 12 | +| 2 | Advanced Queries | 450 | 2021 | 3 | 8 | +| 3 | Database Design | 350 | 2019 | 10 | 15 | +| 4 | Query Optimization | 275 | 2022 | 2 | 6 | +| 5 | Data Modeling | 400 | 2021 | 1 | 4 | +| 6 | PostgreSQL Tips | 200 | 2023 | 8 | 20 | + +Write a query that shows: + +- Book title +- Book length category: + - `Short` if page_count < 300 + - `Medium` if page_count between 300 and 400 + - `Long` if page_count > 400 +- Publication status: + - `Recent` if publish_year >= 2022 + - `Current` if publish_year is 2020 or 2021 + - `Older` if publish_year < 2020 +- Stock status: + - `Low` if copies_in_stock < 3 + - `Medium` if copies_in_stock between 3 and 7 + - `High` if copies_in_stock > 7 +- Popularity: + - `High Demand` if monthly_rentals > 12 + - `Medium Demand` if monthly_rentals between 6 and 12 + - `Low Demand` if monthly_rentals < 6 + +## Expected Output + +| title | length_category | publication_status | stock_status | popularity | +| ------------------ | --------------- | ------------------ | ------------ | ------------- | +| PostgreSQL Tips | Short | Recent | High | High Demand | +| Database Design | Medium | Older | High | High Demand | +| SQL Basics | Short | Current | Medium | Medium Demand | +| Advanced Queries | Long | Current | Medium | Medium Demand | +| Query Optimization | Short | Recent | Low | Medium Demand | + +Data Modeling Medium Current Low Low Demand + +## Solution + +```sql +SELECT + title, + CASE + WHEN page_count < 300 THEN 'Short' + WHEN page_count <= 400 THEN 'Medium' + ELSE 'Long' + END as length_category, + CASE + WHEN publish_year >= 2022 THEN 'Recent' + WHEN publish_year >= 2020 THEN 'Current' + ELSE 'Older' + END as publication_status, + CASE + WHEN copies_in_stock < 3 THEN 'Low' + WHEN copies_in_stock <= 7 THEN 'Medium' + ELSE 'High' + END as stock_status, + CASE + WHEN monthly_rentals > 12 THEN 'High Demand' + WHEN monthly_rentals >= 6 THEN 'Medium Demand' + ELSE 'Low Demand' + END as popularity +FROM books +ORDER BY monthly_rentals DESC; +``` diff --git a/src/data/courses/sql-mastery/chapters/scalar-functions/lessons/customer-contact-list.md b/src/data/courses/sql-mastery/chapters/scalar-functions/lessons/customer-contact-list.md new file mode 100644 index 000000000..f8006c577 --- /dev/null +++ b/src/data/courses/sql-mastery/chapters/scalar-functions/lessons/customer-contact-list.md @@ -0,0 +1,78 @@ +--- +title: Customer Contact List +description: Practice using string and conversion functions to standardize customer contact information +order: 210 +type: challenge +setup: | + ```sql + CREATE TABLE customer ( + id INT PRIMARY KEY, + first_name VARCHAR(50), + last_name VARCHAR(50), + email VARCHAR(255), + phone VARCHAR(20) + ); + + INSERT INTO customer (id, first_name, last_name, email, phone) VALUES + (1, 'john', 'DOE', 'JOHN.DOE@email.com', ' 555-123-4567 '), + (2, 'JANE', 'smith', 'jane.smith@email.com', '555.123.4568'), + (3, 'Bob', 'WILSON', 'bob.wilson@email.com', '5551234569'), + (4, 'ALICE', 'brown', 'alice.b@email.com', NULL), + (5, 'charlie', 'DAVIS', 'charlie.d@email.com', '555-123-4570'); + ``` +--- + +The bookstore is updating their customer contact list and needs to standardize how customer information is displayed. They want all names properly capitalized, emails in lowercase, and phone numbers in a consistent format. + +Given the following data in table `customer` + +| id | first_name | last_name | email | phone | +| --- | ---------- | --------- | -------------------- | ------------ | +| 1 | john | DOE | JOHN.DOE@email.com | 555-123-4567 | +| 2 | JANE | smith | jane.smith@email.com | 555.123.4568 | +| 3 | Bob | WILSON | bob.wilson@email.com | 5551234569 | +| 4 | ALICE | brown | alice.b@email.com | NULL | +| 5 | charlie | DAVIS | charlie.d@email.com | 555-123-4570 | + +Write a query that formats the customer information according to these requirements: + +- Full name (first name and last name properly capitalized) +- Email address (in lowercase) +- Phone number (Numbers only, or `No phone` if `NULL`) + +## Expected Output + +You output should look like this: + +| full_name | email | phone | +| ------------- | -------------------- | ---------- | +| John Doe | john.doe@email.com | 5551234567 | +| Jane Smith | jane.smith@email.com | 5551234568 | +| Bob Wilson | bob.wilson@email.com | 5551234569 | +| Alice Brown | alice.b@email.com | No phone | +| Charlie Davis | charlie.d@email.com | 5551234570 | + +> **Hint:** Use the `REGEXP_REPLACE` function to remove non-numeric characters from the phone number. Use the `g` flag to replace all occurrences of the pattern. + +## Solution + +```sql +SELECT + CONCAT( + INITCAP(first_name), + ' ', + INITCAP(last_name) + ) as full_name, + LOWER(email) as email, + COALESCE( + REGEXP_REPLACE( + TRIM(phone), + '[^0-9]', + '', + 'g' + ), + 'No phone' + ) as phone +FROM customer +ORDER BY id; +``` diff --git a/src/data/courses/sql-mastery/chapters/scalar-functions/lessons/membership-duration.md b/src/data/courses/sql-mastery/chapters/scalar-functions/lessons/membership-duration.md new file mode 100644 index 000000000..58c319e14 --- /dev/null +++ b/src/data/courses/sql-mastery/chapters/scalar-functions/lessons/membership-duration.md @@ -0,0 +1,72 @@ +--- +title: Membership Duration +description: Practice using date functions to calculate membership length and categories +order: 210 +type: challenge +setup: | + ```sql + CREATE TABLE member ( + id INT PRIMARY KEY, + name VARCHAR(100), + join_date DATE + ); + + INSERT INTO member (id, name, join_date) VALUES + (1, 'John Smith', '2022-01-15'), + (2, 'Mary Johnson', '2023-06-20'), + (3, 'Bob Wilson', '2024-01-10'), + (4, 'Alice Brown', '2023-03-01'), + (5, 'Charlie Davis', '2023-12-25'); + ``` +--- + +The bookstore wants to categorize their members based on how long they've been part of the loyalty program. They need a report showing each member's duration and their corresponding membership tier. + +Given the following data in table `member` + +| id | name | join_date | +| --- | ------------- | ---------- | +| 1 | John Smith | 2022-01-15 | +| 2 | Mary Johnson | 2023-06-20 | +| 3 | Bob Wilson | 2024-01-10 | +| 4 | Alice Brown | 2023-03-01 | +| 5 | Charlie Davis | 2023-12-25 | + +Write a query that shows: + +- Member's name +- Number of months they've been a member +- Membership tier: + - `Bronze` if less than 6 months + - `Silver` if between 6 and 12 months + - `Gold` if between 12 and 24 months + - `Platinum` if more than 24 months + +## Expected Output + +| name | months | tier | +| ------------- | ------ | -------- | +| John Smith | 35 | Platinum | +| Alice Brown | 22 | Gold | +| Mary Johnson | 18 | Gold | +| Charlie Davis | 12 | Gold | +| Bob Wilson | 11 | Silver | + +> **Note:** The months will vary based on current date. This example assumes CURRENT_DATE is '2025-01-06'. + +## Solution + +```sql +SELECT + name, + EXTRACT(YEAR FROM AGE(CURRENT_DATE, join_date)) * 12 + + EXTRACT(MONTH FROM AGE(CURRENT_DATE, join_date)) AS months, + CASE + WHEN AGE(CURRENT_DATE, join_date) < INTERVAL '6 months' THEN 'Bronze' + WHEN AGE(CURRENT_DATE, join_date) < INTERVAL '12 months' THEN 'Silver' + WHEN AGE(CURRENT_DATE, join_date) < INTERVAL '24 months' THEN 'Gold' + ELSE 'Platinum' + END AS tier +FROM member +ORDER BY months DESC; +```