File: create-connected-tables.md

package info (click to toggle)
sqlmodel 0.0.25-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid
  • size: 17,456 kB
  • sloc: python: 34,346; javascript: 280; sh: 15; makefile: 7
file content (215 lines) | stat: -rw-r--r-- 6,867 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
# Create Connected Tables

Now we will deal with **connected** data put in different tables.

So, the first step is to create more than one table and connect them, so that each row in one table can reference another row in the other table.

We have been working with heroes in a single table `hero`. Let's now add a table `team`.

The team table will look like this:

<table>
<tr>
<th>id</th><th>name</th><th>headquarters</th>
</tr>
<tr>
<td>1</td><td>Preventers</td><td>Sharp Tower</td>
</tr>
<tr>
<td>2</td><td>Z-Force</td><td>Sister Margaret's Bar</td>
</tr>
</table>

To connect them, we will add another column to the hero table to point to each team by the ID with the `team_id`:

<table>
<tr>
<th>id</th><th>name</th><th>secret_name</th><th>age</th><th>team_id ✨</th>
</tr>
<tr>
<td>1</td><td>Deadpond</td><td>Dive Wilson</td><td>null</td><td>2 ✨</td>
</tr>
<tr>
<td>2</td><td>Spider-Boy</td><td>Pedro Parqueador</td><td>null</td><td>1 ✨</td>
</tr>
<tr>
<td>3</td><td>Rusty-Man</td><td>Tommy Sharp</td><td>48</td><td>1 ✨</td>
</tr>
</table>

This way each row in the table `hero` can point to a row in the table `team`:

<img alt="table relationships" src="/img/databases/relationships.drawio.svg">

## One-to-Many and Many-to-One

Here we are creating connected data in a relationship where **one** team could have **many** heroes. So it is commonly called a **one-to-many** or **many-to-one** relationship.

The **many-to-one** part can be seen if we start from the heroes, **many** heroes could be part of **one** team.

This is probably the most popular type of relationship, so we'll start with that. But there's also **many-to-many** and **one-to-one** relationships.

## Create Tables in Code

### Create the `team` Table

Let's start by creating the tables in code.

Import the things we need from `sqlmodel` and create a new `Team` model:

{* ./docs_src/tutorial/connect/create_tables/tutorial001_py310.py ln[1:7] hl[4:7] *}

This is very similar to what we have been doing with the `Hero` model.

The `Team` model will be in a table automatically named `"team"`, and it will have the columns:

* `id`, the primary key, automatically generated by the database
* `name`, the name of the team
    * We also tell **SQLModel** to create an index for this column
* `headquarters`, the headquarters of the team

And finally we mark it as a table in the config.

### Create the New `hero` Table

Now let's create the `hero` table.

This is the same model we have been using up to now, we are just adding the new column `team_id`:

{* ./docs_src/tutorial/connect/create_tables/tutorial001_py310.py ln[1:16] hl[16] *}

Most of that should look familiar:

The column will be named `team_id`. It will be an integer, and it could be `NULL` in the database (or `None` in Python), because there could be some heroes that don't belong to any team.

We add a default of `None` to the `Field()` so we don't have to explicitly pass `team_id=None` when creating a hero.

Now, here's the new part:

In `Field()` we pass the argument `foreign_key="team.id"`. This tells the database that this column `team_id` is a foreign key to the table `team`. A "**foreign key**" just means that this column will have the **key** to identify a row in a **foreign** table.

The value in this column `team_id` will be the same integer that is in some row in the `id` column on the `team` table. That is what connects the two tables.

#### The Value of `foreign_key`

Notice that the `foreign_key` is a string.

Inside it has the name of the **table**, then a dot, and then the name of the **column**.

This is the name of the **table** in the database, so it is `"team"`, not the name of the **model** class `Team` (with a capital `T`).

If you had a custom table name, you would use that custom table name.

/// info

You can learn about setting a custom table name for a model in the Advanced User Guide.

///

### Create the Tables

Now we can add the same code as before to create the engine and the function to create the tables:

{* ./docs_src/tutorial/connect/create_tables/tutorial001_py310.py ln[19:26] hl[19:20,22,25:26] *}

And as before, we'll call this function from another function `main()`, and we'll add that function `main()` to the main block of the file:

{* ./docs_src/tutorial/connect/create_tables/tutorial001_py310.py ln[29:34] hl[29:30,33:34] *}

## Run the Code

/// tip

Before running the code, make sure you delete the file `database.db` to make sure you start from scratch.

///

If we run the code we have up to now, it will go and create the database file `database.db` and the tables in it we just defined, `team` and `hero`:

<div class="termy">

```console
$ python app.py

// Automatically start a new transaction
INFO Engine BEGIN (implicit)

// Check if the tables exist already
INFO Engine PRAGMA main.table_info("team")
INFO Engine [raw sql] ()
INFO Engine PRAGMA temp.table_info("team")
INFO Engine [raw sql] ()
INFO Engine PRAGMA main.table_info("hero")
INFO Engine [raw sql] ()
INFO Engine PRAGMA temp.table_info("hero")
INFO Engine [raw sql] ()

// Create the tables
INFO Engine
CREATE TABLE team (
        id INTEGER,
        name VARCHAR NOT NULL,
        headquarters VARCHAR NOT NULL,
        PRIMARY KEY (id)
)


INFO Engine [no key 0.00010s] ()
INFO Engine
CREATE TABLE hero (
        id INTEGER,
        name VARCHAR NOT NULL,
        secret_name VARCHAR NOT NULL,
        age INTEGER,
        team_id INTEGER,
        PRIMARY KEY (id),
        FOREIGN KEY(team_id) REFERENCES team (id)
)


INFO Engine [no key 0.00026s] ()
INFO Engine COMMIT
```

</div>

## Create Tables in SQL

Let's see that same generated SQL code.

As we saw before, those `VARCHAR` columns are converted to `TEXT` in SQLite, which is the database we are using for these experiments.

So, the first SQL could also be written as:

```SQL
CREATE TABLE team (
    id INTEGER,
    name TEXT NOT NULL,
    headquarters TEXT NOT NULL,
    PRIMARY KEY (id)
)
```

And the second table could be written as:

```SQL hl_lines="8"
CREATE TABLE hero (
    id INTEGER,
    name TEXT NOT NULL,
    secret_name TEXT NOT NULL,
    age INTEGER,
    team_id INTEGER,
    PRIMARY KEY (id),
    FOREIGN KEY(team_id) REFERENCES team (id)
)
```

The only new  is the `FOREIGN KEY` line, and as you can see, it tells the database what column in this table is a foreign key (`team_id`), which other (foreign) table it references (`team`) and which column in that table is the key to define which row to connect (`id`).

Feel free to experiment with it in **DB Browser for SQLite**.

## Recap

Using **SQLModel**, in most of the cases you only need a field (column) with a `foreign_key` in the `Field()` with a string pointing to another table and column to connect two tables.

Now that we have the tables created and connected, let's create some rows in the next chapter. 🚀