Skip to content

Commit 0cdc1b1

Browse files
committed
Documents using different column types, including string length
1 parent fe497ad commit 0cdc1b1

File tree

10 files changed

+319
-1
lines changed

10 files changed

+319
-1
lines changed

docs/advanced/column-types.md

Lines changed: 152 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,152 @@
1+
# Column Types
2+
3+
In the tutorial, we stored scalar data types in our tables, like strings, numbers and timestamps. In practice, we often
4+
work with more complicated types that need to be converted to a data type our database supports.
5+
6+
## Customising String Field Lengths
7+
8+
As we discussed in [`TEXT` or `VARCHAR`](../tutorial/create-db-and-table.md#text-or-varchar), a `str` field type will be
9+
created as a `VARCHAR`, which has varying maximum-lengths depending on the database engine you are using.
10+
11+
For cases where you know you only need to store a certain length of text, string field maximum length can be reduced
12+
using the `max_length` validation argument to `Field()`:
13+
14+
```Python hl_lines="11"
15+
{!./docs_src/advanced/column_types/tutorial001.py[ln:1-12]!}
16+
```
17+
18+
/// details | 👀 Full file preview
19+
20+
```Python
21+
{!./docs_src/advanced/column_types/tutorial001.py!}
22+
```
23+
24+
///
25+
26+
/// warning
27+
28+
Database engines behave differently when you attempt to store longer text than the character length of the `VARCHAR`
29+
column. Notably:
30+
31+
* SQLite does not enforce the length of a `VARCHAR`. It will happily store up to 500-million characters of text.
32+
* MySQL will emit a warning, but will also truncate your text to fit the size of the `VARCHAR`.
33+
* PostgreSQL will respond with an error code, and your query will not be executed.
34+
35+
///
36+
37+
However if you need to store much longer strings than `VARCHAR` can allow, databases provide `TEXT` or `CLOB`
38+
(**c**haracter **l**arge **ob**ject) column types. We can use these by specifying an SQLAlchemy column type to the field
39+
with the `sa_type` keyword argument:
40+
41+
```Python hl_lines="12"
42+
{!./docs_src/advanced/column_types/tutorial001.py[ln:5-45]!}
43+
```
44+
45+
/// tip
46+
47+
`Text` also accepts a character length argument, which databases use to optimise the storage of a particular field.
48+
Some databases support `TINYTEXT`, `SMALLTEXT`, `MEDIUMTEXT` and `LONGTEXT` column types - ranging from 255 bytes to
49+
4 gigabytes. If you know the maximum length of data, specifying it like `Text(1000)` will automatically select the
50+
best-suited, supported type for your database engine.
51+
52+
///
53+
54+
55+
With this approach, we can use [any kind of SQLAlchemy type](https://docs.sqlalchemy.org/en/20/core/type_basics.html).
56+
For example, if we were building a mapping application, we could store spatial information:
57+
58+
```Python
59+
{!./docs_src/advanced/column_types/tutorial002.py!}
60+
```
61+
62+
## Supported Types
63+
64+
Python types are mapped to column types as so:
65+
66+
<table>
67+
<tr>
68+
<th>Python type</th><th>SQLAlchemy type</th><th>Database column types</th>
69+
</tr>
70+
<tr>
71+
<td>str</td><td>String</td><td>VARCHAR</td>
72+
</tr>
73+
<tr>
74+
<td>int</td><td>Integer</td><td>INTEGER</td>
75+
</tr>
76+
<tr>
77+
<td>float</td><td>Float</td><td>FLOAT, REAL, DOUBLE</td>
78+
</tr>
79+
<tr>
80+
<td>bool</td><td>Boolean</td><td>BOOL or TINYINT</td>
81+
</tr>
82+
<tr>
83+
<td>datetime.datetime</td><td>DateTime</td><td>DATETIME, TIMESTAMP, DATE</td>
84+
</tr>
85+
<tr>
86+
<td>datetime.date</td><td>Date</td><td>DATE</td>
87+
</tr>
88+
<tr>
89+
<td>datetime.timedelta</td><td>Interval</td><td>INTERVAL, INT</td>
90+
</tr>
91+
<tr>
92+
<td>datetime.time</td><td>Time</td><td>TIME, DATETIME</td>
93+
</tr>
94+
<tr>
95+
<td>bytes</td><td>LargeBinary</td><td>BLOB, BYTEA</td>
96+
</tr>
97+
<tr>
98+
<td>Decimal</td><td>Numeric</td><td>DECIMAL, FLOAT</td>
99+
</tr>
100+
<tr>
101+
<td>enum.Enum</td><td>Enum</td><td>ENUM, VARCHAR</td>
102+
</tr>
103+
<tr>
104+
<td>uuid.UUID</td><td>GUID</td><td>UUID, CHAR(32)</td>
105+
</tr>
106+
</table>
107+
108+
In addition, the following types are stored as `VARCHAR`:
109+
110+
* ipaddress.IPv4Address
111+
* ipaddress.IPv4Network
112+
* ipaddress.IPv6Address
113+
* ipaddress.IPv6Network
114+
* pathlib.Path
115+
116+
### IP Addresses
117+
118+
IP Addresses from the <a href="https://docs.python.org/3/library/ipaddress.html" class="external-link" target="_blank">Python `ipaddress` module</a> are stored as text.
119+
120+
```Python hl_lines="1 11"
121+
{!./docs_src/advanced/column_types/tutorial003.py[ln:1-13]!}
122+
```
123+
124+
### Filesystem Paths
125+
126+
Paths to files and directories using the <a href="https://docs.python.org/3/library/pathlib.html" class="external-link" target="_blank">Python `pathlib` module</a> are stored as text.
127+
128+
```Python hl_lines="3 12"
129+
{!./docs_src/advanced/column_types/tutorial003.py[ln:1-13]!}
130+
```
131+
132+
/// tip
133+
134+
The stored value of a Path is the basic string value: `str(Path('../path/to/file'))`. If you need to store the full path
135+
ensure you call `absolute()` on the path before setting it in your model.
136+
137+
///
138+
139+
### UUIDs
140+
141+
UUIDs from the <a href="https://docs.python.org/3/library/uuid.html" class="external-link" target="_blank">Python `uuid`
142+
module</a> are stored as `UUID` types in supported databases (just PostgreSQL at the moment), otherwise as a `CHAR(32)`.
143+
144+
```Python hl_lines="4 10"
145+
{!./docs_src/advanced/column_types/tutorial003.py[ln:1-13]!}
146+
```
147+
148+
## Custom Pydantic types
149+
150+
As SQLModel is built on Pydantic, you can use any custom type as long as it would work in a Pydantic model. However, if
151+
the type is not a subclass of [a type from the table above](#supported-types), you will need to specify an SQLAlchemy
152+
type to use.

docs/tutorial/create-db-and-table.md

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -500,7 +500,7 @@ To make it easier to start using **SQLModel** right away independent of the data
500500

501501
/// tip
502502

503-
You will learn how to change the maximum length of string columns later in the Advanced Tutorial - User Guide.
503+
You can learn how to change the maximum length of string columns later in the [Advanced Tutorial - User Guide](../advanced/column-types.md){.internal-link target=_blank}.
504504

505505
///
506506

docs_src/advanced/column_types/__init__.py

Whitespace-only changes.
Lines changed: 80 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,80 @@
1+
from typing import Optional
2+
3+
from sqlalchemy import Text
4+
from sqlmodel import Field, Session, SQLModel, create_engine, select
5+
from wonderwords import RandomWord
6+
7+
8+
class Villian(SQLModel, table=True):
9+
id: Optional[int] = Field(default=None, primary_key=True)
10+
name: str = Field(index=True)
11+
country_code: str = Field(max_length=2)
12+
backstory: str = Field(sa_type=Text())
13+
14+
15+
sqlite_file_name = "database.db"
16+
sqlite_url = f"sqlite:///{sqlite_file_name}"
17+
18+
engine = create_engine(sqlite_url, echo=True)
19+
20+
21+
def create_db_and_tables():
22+
SQLModel.metadata.create_all(engine)
23+
24+
25+
def generate_backstory(words: int) -> str:
26+
return " ".join(RandomWord().random_words(words, regex=r"\S+"))
27+
28+
29+
def create_villains():
30+
villian_1 = Villian(
31+
name="Green Gobbler", country_code="US", backstory=generate_backstory(500)
32+
)
33+
villian_2 = Villian(
34+
name="Arnim Zozza", country_code="DE", backstory=generate_backstory(500)
35+
)
36+
villian_3 = Villian(
37+
name="Low-key", country_code="AS", backstory=generate_backstory(500)
38+
)
39+
40+
with Session(engine) as session:
41+
session.add(villian_1)
42+
session.add(villian_2)
43+
session.add(villian_3)
44+
45+
session.commit()
46+
47+
48+
def count_words(sentence: str) -> int:
49+
return sentence.count(" ") + 1
50+
51+
52+
def select_villians():
53+
with Session(engine) as session:
54+
statement = select(Villian).where(Villian.name == "Green Gobbler")
55+
results = session.exec(statement)
56+
villian_1 = results.one()
57+
print(
58+
"Villian 1:",
59+
{"name": villian_1.name, "country_code": villian_1.country_code},
60+
count_words(villian_1.backstory),
61+
)
62+
63+
statement = select(Villian).where(Villian.name == "Low-key")
64+
results = session.exec(statement)
65+
villian_2 = results.one()
66+
print(
67+
"Villian 2:",
68+
{"name": villian_2.name, "country_code": villian_2.country_code},
69+
count_words(villian_1.backstory),
70+
)
71+
72+
73+
def main():
74+
create_db_and_tables()
75+
create_villains()
76+
select_villians()
77+
78+
79+
if __name__ == "__main__":
80+
main()
Lines changed: 17 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,17 @@
1+
from typing import Optional
2+
3+
from geoalchemy2.types import Geography
4+
from sqlmodel import Field, SQLModel, create_engine
5+
6+
7+
class BusStop(SQLModel, table=True):
8+
id: Optional[int] = Field(default=..., primary_key=True)
9+
latlng: Geography = Field(sa_type=Geography(geometry_type="POINT", srid=4326))
10+
11+
12+
sqlite_file_name = "database.db"
13+
sqlite_url = f"sqlite:///{sqlite_file_name}"
14+
15+
engine = create_engine(sqlite_url, echo=True)
16+
17+
SQLModel.metadata.create_all(engine)
Lines changed: 21 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,21 @@
1+
import ipaddress
2+
from datetime import UTC, datetime
3+
from pathlib import Path
4+
from uuid import UUID, uuid4
5+
6+
from sqlmodel import Field, SQLModel, create_engine
7+
8+
9+
class Avatar(SQLModel, table=True):
10+
id: UUID = Field(default_factory=uuid4, primary_key=True)
11+
source_ip_address: ipaddress.IPv4Address
12+
upload_location: Path
13+
uploaded_at: datetime = Field(default=datetime.now(tz=UTC))
14+
15+
16+
sqlite_file_name = "database.db"
17+
sqlite_url = f"sqlite:///{sqlite_file_name}"
18+
19+
engine = create_engine(sqlite_url, echo=True)
20+
21+
SQLModel.metadata.create_all(engine)

mkdocs.yml

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -98,6 +98,7 @@ nav:
9898
- Advanced User Guide:
9999
- advanced/index.md
100100
- advanced/decimal.md
101+
- advanced/column-types.md
101102
- alternatives.md
102103
- help.md
103104
- contributing.md

pyproject.toml

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -54,6 +54,9 @@ httpx = "0.24.1"
5454
dirty-equals = "^0.6.0"
5555
typer-cli = "^0.0.13"
5656
mkdocs-markdownextradata-plugin = ">=0.1.7,<0.3.0"
57+
# For column type tests
58+
wonderwords = "^2.2.0"
59+
geoalchemy2 = "^0.14.3"
5760

5861
[build-system]
5962
requires = ["poetry-core"]

tests/test_advanced/test_column_types/__init__.py

Whitespace-only changes.
Lines changed: 44 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,44 @@
1+
from unittest.mock import patch
2+
3+
from sqlmodel import create_engine
4+
5+
from ...conftest import get_testing_print_function
6+
7+
expected_calls = [
8+
[
9+
"Villian 1:",
10+
{
11+
"name": "Green Gobbler",
12+
"country_code": "US",
13+
},
14+
500,
15+
],
16+
[
17+
"Villian 2:",
18+
{
19+
"name": "Low-key",
20+
"country_code": "AS",
21+
},
22+
500,
23+
],
24+
]
25+
26+
27+
def test_tutorial(clear_sqlmodel):
28+
"""
29+
Unfortunately, SQLite does not enforce varchar lengths, so we can't test an oversize case without spinning up a
30+
database engine.
31+
32+
"""
33+
34+
from docs_src.advanced.column_types import tutorial001 as mod
35+
36+
mod.sqlite_url = "sqlite://"
37+
mod.engine = create_engine(mod.sqlite_url)
38+
calls = []
39+
40+
new_print = get_testing_print_function(calls)
41+
42+
with patch("builtins.print", new=new_print):
43+
mod.main()
44+
assert calls == expected_calls

0 commit comments

Comments
 (0)