generated from btholt/next-course-starter
-
Notifications
You must be signed in to change notification settings - Fork 10
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
2 changed files
with
138 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,26 @@ | ||
We can actually make that relationship between IDs explicit. We can make it so `AlbumId` isn't just an implicit relationship but an actual relationship tracked by SQLite itself. This relationship is called a foreign key: a key that references foreign information in another table. Our Chinook database already has these relationships built in. Type `.schema Track` and notice the FOREIGN KEY part on MediaTypeId, GenreId, and AlbumId. | ||
|
||
> SQLite does not enforce foreign key rules by default. Every time you open the database connection you need to tell it respect it with `PRAGMA foreign_keys=on;`. Yes, it's by connection, and no, there's no way to always turn it on. Probably my biggest complaint about SQLite. It's done for historical / compat reasons. | ||
```sql | ||
PRAGMA foreign_keys=on; | ||
|
||
INSERT INTO | ||
Track | ||
(Name, AlbumId, MediaTypeId, Composer, Milliseconds, Bytes, UnitPrice) | ||
VALUES | ||
('lol', 99999, 99999, 99999, 99999, 99999, 99999); | ||
|
||
DELETE FROM | ||
Genre | ||
WHERE | ||
GenreId=24; | ||
``` | ||
|
||
> Both of those queries should fail due to foreign key constraints. | ||
- PRAGMAs are basically policies you can tell SQLite to respect. In this case, we are saying for _this_ connection, please enforce rules around foreign keys. You need to do this for every connection to SQLite. There's a bunch but I tend not to use too many of them. | ||
- You can actually set the foreign key pragma in the connection string when you connect in code. I'll show you how later. | ||
- Notice it won't let us neither insert with violations of the constraint nor delete. | ||
- You can also do `ON UPDATE` constraints as well. | ||
- We did a `NO ACTION` constraint, but there are others as well. NO ACTION means that if a foreign key relationship would be severed and thus leave orphan rows, error out the query. `RESTRICT` does this as well (but has some minuet difference that has never been important to me.) `ON DELETE CASCADE` will delete any affected rows. So if I delete "rock" from the Genre table, it will go delete every rock track from the Track table. You can also do `ON DELETE SET NULL` and `ON DELETE SET DEFAULT` to just change what the value. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,112 @@ | ||
--- | ||
description: "" | ||
--- | ||
|
||
Occasionally you need to query for macro statistics about your tables, not just query for individual rows. | ||
|
||
Let's use that we've already used before, `COUNT`. What if we want to know how many tracks we have overall in our track table? | ||
|
||
```sql | ||
SELECT COUNT(*) FROM Track; | ||
``` | ||
|
||
`COUNT` is an aggregation function. We give the `*` is saying "count everything and don't remove nulls or duplicates of any variety". | ||
|
||
What if we wanted to count how many distinct `genre`s of tracks we have in the Track table? | ||
|
||
```sql | ||
SELECT COUNT(DISTINCT GenreId) FROM Track; | ||
``` | ||
|
||
This is going to tell how many different `type`s we have in the ingredients table. Keep in mind the query to see _what_ the distinct ingredients is | ||
|
||
```sql | ||
SELECT DISTINCT GenreId FROM Track; | ||
``` | ||
|
||
The first query gives you the number, the count of many distinct things are in the list. The second query gives you what those distinct things are with no indication of how many of each there are. There could be 1 fruit and 10,000 vegetables and you'd have no indication of that. | ||
|
||
Okay, so you want to see both at the same time? Let's see that. | ||
|
||
```sql | ||
SELECT | ||
GenreId, COUNT(GenreId) | ||
FROM | ||
Track | ||
GROUP BY | ||
GenreId; | ||
``` | ||
|
||
This is combining both of what we saw plus a new thing, `GROUP BY`. This allows us to specify what things we want to aggregate together: the type. Keep in mind if you want to SELECT for something with a GROUP BY clause, you do need to put them in the GROUP BY clause. | ||
|
||
Now what if we want to include the actual genre names? | ||
|
||
```sql | ||
SELECT | ||
Track.GenreId, Genre.Name, COUNT(Track.GenreId) | ||
FROM | ||
Track | ||
JOIN | ||
Genre | ||
ON | ||
Genre.GenreId = Track.GenreId | ||
GROUP BY | ||
Track.GenreId; -- you can also have Genre.GenreId here, no difference | ||
``` | ||
|
||
This one can be a bit of a mind trip. Remember the aggregation happens at the end. So all your select happens, then on the row set, it goes and runs the aggregation function here using the GROUP BY. So we get a bunch of rows with their Genre.Name attached, and then we count those up. | ||
|
||
What if we wanted to find the biggest or smallest TrackId with each genre? (Doesn't seem that useful but I'll still show you how.) | ||
|
||
```sql | ||
SELECT | ||
Track.GenreId, Genre.Name, MAX(Track.TrackId) -- MIN(Track.TrackId) | ||
FROM | ||
Track | ||
JOIN | ||
Genre | ||
ON | ||
Genre.GenreId = Track.GenreId | ||
GROUP BY | ||
Track.GenreId; | ||
``` | ||
|
||
## HAVING | ||
|
||
What if you only want genres that have more than 300 tracks? | ||
|
||
> The following query does not work. | ||
```sql | ||
SELECT | ||
Track.GenreId, Genre.Name, COUNT(Track.GenreId) | ||
FROM | ||
Track | ||
JOIN | ||
Genre | ||
ON | ||
Genre.GenreId = Track.GenreId | ||
WHERE | ||
COUNT(Track.GenreId) > 500 | ||
GROUP BY | ||
Track.GenreId; | ||
``` | ||
|
||
You can't use WHERE because that applies to the initial result set. You could filter out all rock songs or only select tracks with a certain length. But you can't filter based on the aggregated values because that happens after WHERE happens. This is HAVING is useful. | ||
|
||
```sql | ||
SELECT | ||
Track.GenreId, Genre.Name, COUNT(Track.GenreId) | ||
FROM | ||
Track | ||
JOIN | ||
Genre | ||
ON | ||
Genre.GenreId = Track.GenreId | ||
GROUP BY | ||
Track.GenreId | ||
HAVING | ||
COUNT(Track.GenreId) > 300; | ||
``` | ||
|
||
Using HAVING we can filter on the aggregated set. |