Skip to content

Commit f134348

Browse files
Add CASE docs to SQL docs.
1 parent 1cfb975 commit f134348

File tree

1 file changed

+106
-0
lines changed

1 file changed

+106
-0
lines changed

docs/sql/sql-language.md

Lines changed: 106 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -18,6 +18,7 @@ You'll also find many _Further reading_ sections, which pull from these excellen
1818
- [SQLBolt](https://sqlbolt.com/lesson/introduction)
1919
- [SQLite Tutorial](https://www.sqlitetutorial.net/)
2020
- [Python.org Documentation](https://www.python.org/doc/)
21+
- [Mode SQL Tutorial](https://mode.com/sql-tutorial/)
2122

2223
<hr>
2324

@@ -526,6 +527,111 @@ The total price of all computers in the `products` table:
526527

527528
- [SQLBolt - Queries with expressions](https://sqlbolt.com/lesson/select_queries_with_expressions)
528529

530+
## CASE
531+
532+
The `CASE` statement is similar to a chain of conditional statements in a language like Python or JavaScript. You use it to generate different values based on some condition. At CWHQ, we use the `CASE` statement to generate an additional column with a range of values generated from our other columns.
533+
534+
Consider a shopping app where we want to rank products by their affordability. Any product that costs $100 or less is considered "Cheap", any product between $100 and $1000 is considered "Affordable", and anything else is "Expensive".
535+
536+
Our `products` table has the following structure:
537+
538+
```sql
539+
SELECT * FROM products;
540+
541+
┌────────────┬──────────────────────────┬───────────────┬──────────────────┐
542+
│ product_id │ product_name │ product_price │ product_category │
543+
├────────────┼──────────────────────────┼───────────────┼──────────────────┤
544+
1 │ Dell XPS 171599.99 │ Computers │
545+
2 │ Blue Snowball Microphone │ 99.5 │ Microphones │
546+
3 │ System76 Thelio B1 │ 1255.55 │ Computers │
547+
4 │ Logitech M1 │ 34.99 │ Accessories │
548+
5 │ Seagate S1 SSD │ 88.75 │ Accessories │
549+
6 │ MacBook Pro 162100.5 │ Computers │
550+
7 │ Rode Z28 │ 275.99 │ Microphones │
551+
8 │ Lenovo ThinkPad │ 950.75 │ Computers │
552+
└────────────┴──────────────────────────┴───────────────┴──────────────────┘
553+
```
554+
555+
Notice that there is no `affordability` column? We can create one and populate it with values based on the `product_price` by using the `CASE` statement and using `AS` to ensure the result is placed in a column called `affordability`.
556+
557+
The `THEN` keyword is what populates the values in whatever column name we created with `END AS`. If you have an `ELSE` clause, it doesn't need a `THEN` clause.
558+
559+
**Raw SQL**
560+
561+
```sql
562+
SELECT product_name, product_price,
563+
CASE
564+
WHEN product_price <= 100
565+
THEN 'Cheap'
566+
WHEN product_price > 100 AND product_price <= 1000
567+
THEN 'Affordable'
568+
ELSE
569+
'Expensive'
570+
END AS affordability
571+
FROM products
572+
ORDER BY product_price;
573+
574+
┌──────────────────────────┬───────────────┬───────────────┐
575+
│ product_name │ product_price │ affordability │
576+
├──────────────────────────┼───────────────┼───────────────┤
577+
│ Logitech M1 │ 34.99 │ Cheap │
578+
│ Seagate S1 SSD │ 88.75 │ Cheap │
579+
│ Blue Snowball Microphone │ 99.5 │ Cheap │
580+
│ Rode Z28 │ 275.99 │ Affordable │
581+
│ Lenovo ThinkPad │ 950.75 │ Affordable │
582+
│ System76 Thelio B1 │ 1255.55 │ Expensive │
583+
│ Dell XPS 171599.99 │ Expensive │
584+
│ MacBook Pro 162100.5 │ Expensive │
585+
└──────────────────────────┴───────────────┴───────────────┘
586+
```
587+
588+
**Python + SQL**
589+
590+
```python
591+
import sqlite3
592+
593+
con = sqlite3.connect("products.db")
594+
sql = con.cursor()
595+
596+
query = """
597+
SELECT product_name, product_price,
598+
CASE
599+
WHEN product_price <= 100
600+
THEN 'Cheap'
601+
WHEN product_price > 100 AND product_price <= 1000
602+
THEN 'Affordable'
603+
ELSE
604+
'Expensive'
605+
END AS affordability
606+
FROM products
607+
ORDER BY product_price;
608+
"""
609+
610+
result = sql.execute(query)
611+
rows = result.fetchall()
612+
613+
for row in rows:
614+
print(row)
615+
616+
```
617+
618+
**Output**
619+
620+
```text
621+
('Logitech M1', 34.99, 'Cheap')
622+
('Seagate S1 SSD', 88.75, 'Cheap')
623+
('Blue Snowball Microphone', 99.5, 'Cheap')
624+
('Rode Z28', 275.99, 'Affordable')
625+
('Lenovo ThinkPad', 950.75, 'Affordable')
626+
('System76 Thelio B1', 1255.55, 'Expensive')
627+
('Dell XPS 17', 1599.99, 'Expensive')
628+
('MacBook Pro 16', 2100.5, 'Expensive')
629+
```
630+
631+
**Further Reading**
632+
633+
- [Mode SQL Tutorial - SQL CASE](https://mode.com/sql-tutorial/sql-case/)
634+
529635
## Concatenation
530636

531637
SQLite uses the `||` operator for string concatenation. This is used at CWHQ to combine column names together (possibly with other string data) to merge the data from multiple columns into a single column. This is often used in conjunction with the `AS` clause to rename the combined columns.

0 commit comments

Comments
 (0)