Skip to content

Commit

Permalink
Add postgres day 2 homework
Browse files Browse the repository at this point in the history
  • Loading branch information
peferron committed Nov 6, 2016
1 parent ad56940 commit 3e8241e
Show file tree
Hide file tree
Showing 3 changed files with 329 additions and 13 deletions.
3 changes: 2 additions & 1 deletion README.md
Original file line number Diff line number Diff line change
@@ -1,2 +1,3 @@
# 7dbs-in-7wks
Code from the "Seven Databases in Seven Weeks" book.

Source code from the book is available on the [official website](https://pragprog.com/book/rwdata/seven-databases-in-seven-weeks).
1 change: 1 addition & 0 deletions postgres/.gitignore
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
*.sql
338 changes: 326 additions & 12 deletions postgres/homework.md
Original file line number Diff line number Diff line change
Expand Up @@ -2,26 +2,340 @@

## Day 1

1. Select all the tables we created (and only those) from `pg_class`.

### 1.

```
SELECT relname FROM pg_class
WHERE relname !~ '^(pg_|sql_)'
AND relkind = 'r';
```

### 2.

```
SELECT c.country_name FROM countries c
JOIN venues v ON c.country_code = v.country_code
JOIN events e ON v.venue_id = e.venue_id
WHERE e.title = 'LARP Club';
```

### 3.

```
ALTER TABLE venues
ADD COLUMN active BOOLEAN DEFAULT TRUE;
```

## Day 2

### 1.

```
CREATE RULE delete_venue
AS ON DELETE TO venues DO INSTEAD
UPDATE venues SET active = false WHERE venue_id = OLD.venue_id;
```

### 2.

```
SELECT * FROM generate_series(1, 12);
```

### 3.

This exercise is fairly difficult. Here are the steps I followed.

1. We want a final result like this (`wom` is the index of the week in the month):

```
SELECT relname FROM pg_class
WHERE relname !~ '^(pg_|sql_)'
AND relkind = 'r';
wom | sun | mon | tue | wed | thu | fri | sat
-----+-----+-----+-----+-----+-----+-----+-----
0 | | | | | | |
1 | | | | | | |
2 | | | 1 | 1 | | |
3 | 2 | | | | | |
4 | | | | | | |
```


2. Write a query that finds the country name of the LARP Club event.
2. We know a `crosstab` can achieve the above if we feed it a table like this:

```
SELECT c.country_name FROM countries c
JOIN venues v ON c.country_code = v.country_code
JOIN events e ON v.venue_id = e.venue_id
WHERE e.title = 'LARP Club';
wom | dow | count
-----+-----+-------
0 | 3 |
0 | 4 |
0 | 5 |
0 | 6 |
0 | 0 |
1 | 1 |
1 | 2 |
1 | 3 |
1 | 4 |
1 | 5 |
1 | 6 |
1 | 0 |
2 | 1 |
2 | 2 | 1
2 | 3 | 1
2 | 4 |
2 | 5 |
2 | 6 |
2 | 0 |
3 | 1 |
3 | 2 |
3 | 3 |
3 | 4 |
3 | 5 |
3 | 6 |
3 | 0 | 2
4 | 1 |
4 | 2 |
4 | 3 |
```

3. So we need to start by listing all the days in the month (we'll pick February 2012 since it has the most events):

3. Alter the `venues` table to contain a boolean column called `active`, with the default value of `true`.
```
SELECT date
FROM generate_series(
'2012-02-01'::date,
'2012-02-29'::date,
'1 day'::interval
) AS date;
```
```
date
------------------------
2012-02-01 00:00:00+01
2012-02-02 00:00:00+01
2012-02-03 00:00:00+01
2012-02-04 00:00:00+01
2012-02-05 00:00:00+01
2012-02-06 00:00:00+01
2012-02-07 00:00:00+01
2012-02-08 00:00:00+01
2012-02-09 00:00:00+01
2012-02-10 00:00:00+01
2012-02-11 00:00:00+01
2012-02-12 00:00:00+01
2012-02-13 00:00:00+01
2012-02-14 00:00:00+01
2012-02-15 00:00:00+01
2012-02-16 00:00:00+01
2012-02-17 00:00:00+01
2012-02-18 00:00:00+01
2012-02-19 00:00:00+01
2012-02-20 00:00:00+01
2012-02-21 00:00:00+01
2012-02-22 00:00:00+01
2012-02-23 00:00:00+01
2012-02-24 00:00:00+01
2012-02-25 00:00:00+01
2012-02-26 00:00:00+01
2012-02-27 00:00:00+01
2012-02-28 00:00:00+01
2012-02-29 00:00:00+01
```

2. Then join with the events table:

```
ALTER TABLE venues
ADD COLUMN active BOOLEAN DEFAULT TRUE;
SELECT date, title
FROM (
SELECT date
FROM generate_series(
'2012-02-01'::date,
'2012-02-29'::date,
'1 day'::interval
) AS date
) AS dates
LEFT JOIN events
ON date = date_trunc('day', starts);
```
```
date | title
------------------------+-----------------
2012-02-01 00:00:00+01 |
2012-02-02 00:00:00+01 |
2012-02-03 00:00:00+01 |
2012-02-04 00:00:00+01 |
2012-02-05 00:00:00+01 |
2012-02-06 00:00:00+01 |
2012-02-07 00:00:00+01 |
2012-02-08 00:00:00+01 |
2012-02-09 00:00:00+01 |
2012-02-10 00:00:00+01 |
2012-02-11 00:00:00+01 |
2012-02-12 00:00:00+01 |
2012-02-13 00:00:00+01 |
2012-02-14 00:00:00+01 | Valentine's Day
2012-02-15 00:00:00+01 | LARP Club
2012-02-16 00:00:00+01 |
2012-02-17 00:00:00+01 |
2012-02-18 00:00:00+01 |
2012-02-19 00:00:00+01 |
2012-02-20 00:00:00+01 |
2012-02-21 00:00:00+01 |
2012-02-22 00:00:00+01 |
2012-02-23 00:00:00+01 |
2012-02-24 00:00:00+01 |
2012-02-25 00:00:00+01 |
2012-02-26 00:00:00+01 | Wedding
2012-02-26 00:00:00+01 | Dinner with Mom
2012-02-27 00:00:00+01 |
2012-02-28 00:00:00+01 |
2012-02-29 00:00:00+01 |
```

3. Show the count instead of the title:

```
SELECT date, NullIf(count(events), 0) AS count
FROM (
SELECT date
FROM generate_series(
'2012-02-01'::date,
'2012-02-29'::date,
'1 day'::interval
) AS date
) AS dates
LEFT JOIN events
ON date = date_trunc('day', starts)
GROUP BY date
ORDER BY date;
```
```
date | count
------------------------+-------
2012-02-01 00:00:00+01 |
2012-02-02 00:00:00+01 |
2012-02-03 00:00:00+01 |
2012-02-04 00:00:00+01 |
2012-02-05 00:00:00+01 |
2012-02-06 00:00:00+01 |
2012-02-07 00:00:00+01 |
2012-02-08 00:00:00+01 |
2012-02-09 00:00:00+01 |
2012-02-10 00:00:00+01 |
2012-02-11 00:00:00+01 |
2012-02-12 00:00:00+01 |
2012-02-13 00:00:00+01 |
2012-02-14 00:00:00+01 | 1
2012-02-15 00:00:00+01 | 1
2012-02-16 00:00:00+01 |
2012-02-17 00:00:00+01 |
2012-02-18 00:00:00+01 |
2012-02-19 00:00:00+01 |
2012-02-20 00:00:00+01 |
2012-02-21 00:00:00+01 |
2012-02-22 00:00:00+01 |
2012-02-23 00:00:00+01 |
2012-02-24 00:00:00+01 |
2012-02-25 00:00:00+01 |
2012-02-26 00:00:00+01 | 2
2012-02-27 00:00:00+01 |
2012-02-28 00:00:00+01 |
2012-02-29 00:00:00+01 |
```

4. Show the week of month and day of week instead of the date:

```
SELECT
extract(week from date) - extract(week from date_trunc('month', date)) AS wom,
extract(dow from date) AS dow,
NullIf(count(events), 0) AS count
FROM (
SELECT date
FROM generate_series(
'2012-02-01'::date,
'2012-02-29'::date,
'1 day'::interval
) AS date
) AS dates
LEFT JOIN events
ON date = date_trunc('day', starts)
GROUP BY date
ORDER BY date;
```
```
wom | dow | count
-----+-----+-------
0 | 3 |
0 | 4 |
0 | 5 |
0 | 6 |
0 | 0 |
1 | 1 |
1 | 2 |
1 | 3 |
1 | 4 |
1 | 5 |
1 | 6 |
1 | 0 |
2 | 1 |
2 | 2 | 1
2 | 3 | 1
2 | 4 |
2 | 5 |
2 | 6 |
2 | 0 |
3 | 1 |
3 | 2 |
3 | 3 |
3 | 4 |
3 | 5 |
3 | 6 |
3 | 0 | 2
4 | 1 |
4 | 2 |
4 | 3 |
```

5. We're now ready for the `crosstab`:

```
SELECT * from crosstab(
'SELECT
extract(week from date) - extract(week from date_trunc(''month'', date)) AS wom,
extract(dow from date) AS dow,
NullIf(count(events), 0) AS count
FROM (
SELECT date
FROM generate_series(
''2012-02-01''::date,
''2012-02-29''::date,
''1 day''::interval
) AS date
) AS dates
LEFT JOIN events
ON date = date_trunc(''day'', starts)
GROUP BY date
ORDER BY date',
'SELECT * from generate_series(0, 6)'
) AS (
wom int,
sun int, mon int, tue int, wed int, thu int, fri int, sat int
)
ORDER BY wom;
```

```
wom | sun | mon | tue | wed | thu | fri | sat
-----+-----+-----+-----+-----+-----+-----+-----
0 | | | | | | |
1 | | | | | | |
2 | | | 1 | 1 | | |
3 | 2 | | | | | |
4 | | | | | | |
(5 rows)
```

Yay!

0 comments on commit 3e8241e

Please sign in to comment.