-
Notifications
You must be signed in to change notification settings - Fork 22
/
Copy pathsqlalchemy-relationships-2.html
208 lines (184 loc) · 6.48 KB
/
sqlalchemy-relationships-2.html
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
<html>
<meta content="width=device-width, initial-scale=1.0" name="viewport">
<head>
<title>
leontrolski - SQLAlchemy relationships TLDR
</title>
<style>
body {margin: 5% auto; background: #fff7f7; color: #444444; font-family: -apple-system, BlinkMacSystemFont, "Segoe UI", Roboto, Helvetica, Arial, sans-serif; font-size: 16px; line-height: 1.8; max-width: 63%;}
@media screen and (max-width: 800px) {body {font-size: 14px; line-height: 1.4; max-width: 90%;}}
pre {width: 100%; border-top: 3px solid gray; border-bottom: 3px solid gray;}
a {border-bottom: 1px solid #444444; color: #444444; text-decoration: none; text-shadow: 0 1px 0 #ffffff; }
a:hover {border-bottom: 0;}
.inline {background: #b3b2b226; padding-left: 0.3em; padding-right: 0.3em; white-space: nowrap;}
blockquote {font-style: italic;color:black;background-color:#f2f2f2;padding:2em;}
details {border-bottom:solid 5px gray;}
</style>
<link href="https://unpkg.com/[email protected]/themes/prism-vs.css" rel="stylesheet">
<script src="https://cdnjs.cloudflare.com/ajax/libs/prism/1.20.0/components/prism-core.min.js">
</script>
<script src="https://cdnjs.cloudflare.com/ajax/libs/prism/1.20.0/plugins/autoloader/prism-autoloader.min.js">
</script>
</head>
<body>
<a href="index.html">
<img src="pic.png" style="height:2em">
⇦
</a>
<p><i>2023-11-16</i></p>
<h1>
SQLAlchemy relationship loading techniques TLDR - v2
</h1>
<p>
The <a href="https://docs.sqlalchemy.org/en/20/orm/queryguide/relationships.html">
SQLAlchemy docs for relationship loading techniques
</a>
are great and have some useful examples.
</p>
<p>
This is a TLDR for those in a hurry who can never remember the difference between a <code class="inline">subqueryload</code>
and a <code class="inline">selectinload</code>
.
</p>
<br>
<details>
<summary>
Users have many Baskets, simple! Here's our set up code.
</summary>
<pre class="language-python"><code>from __future__ import annotations
from sqlalchemy import (
ForeignKey,
create_engine,
select,
)
from sqlalchemy.orm import (
DeclarativeBase,
Mapped,
Session,
mapped_column,
relationship,
lazyload,
joinedload,
subqueryload,
selectinload,
raiseload,
noload,
)
class Base(DeclarativeBase):
pass
class User(Base):
__tablename__ = "user"
user_id: Mapped[int] = mapped_column(primary_key=True)
name: Mapped[str]
baskets: Mapped[list[Basket]] = relationship(lazy="raise")
class Basket(Base):
__tablename__ = "basket"
basket_id: Mapped[int] = mapped_column(primary_key=True)
user_id: Mapped[int] = mapped_column(ForeignKey(User.user_id))
price: Mapped[int]
engine = create_engine("sqlite://", echo=True)
Base.metadata.create_all(engine)
with Session(engine) as session:
users = [
User(
name="ben",
baskets=[Basket(price=1), Basket(price=2)],
),
User(
name="si",
baskets=[Basket(price=3), Basket(price=4)],
),
User(
name="si",
baskets=[Basket(price=5)],
),
]
session.add_all(users)
session.commit()</code></pre>
</details>
<br>
<br>
<b>
Note from the above:
</b>
<pre class="language-python"><code>relationship(lazy="raise")</code>
</pre>
<b>
This should probably be the default as it forces you to pick a loading technique at query time.
</b>
<br>
<br>
<p>
The N+1 (where N is the number of Users) looking bit of code we're going to write at is:
</p>
<pre class="language-python"><code>qry = (
select(User)
.where(User.name == "si")
.options(someloadingtechnique(User.baskets))
)
for user in session.execute(qry).unique().scalars(): # Point A
print(f"User: {user.user_id}")
for basket in user.baskets: # Point B
print(f"Basket {basket.basket_id}")</code></pre>
<p>
We're going to swap out <code class="inline">someloadingtechnique</code>
with each of SQLAlchemy's and inspect the SQL.
</p>
<br>
<pre class="language-python"><code>.options(lazyload(User.baskets)) # SQLAlchemy's default on a relationship</code>
</pre>
<pre class="language-sql"><code>-- At point A
SELECT ...
FROM user
WHERE user.name = ?</code>
</pre>
<pre class="language-sql"><code>-- Each time at point B - classic N+1!
SELECT ...
FROM basket
WHERE ? = basket.user_id</code>
</pre>
<br>
<pre class="language-python"><code>.options(joinedload(User.baskets)) # I'm informed this is similar to Django's select_related</code>
</pre>
<pre class="language-sql"><code>-- At point A, nothing at point B
SELECT ...
FROM user
LEFT OUTER JOIN basket ON user.user_id = basket.user_id
WHERE user.name = ?</code>
</pre>
<br>
<pre class="language-python"><code>.options(subqueryload(User.baskets))</code>
</pre>
<pre class="language-sql"><code>-- At point A, nothing at point B
SELECT ...
FROM (
SELECT user.user_id AS user_user_id
FROM user
WHERE user.name = ?
) AS anon_1
JOIN basket ON anon_1.user_user_id = basket.user_id</code>
</pre>
<br>
<pre class="language-python"><code>.options(selectinload(User.baskets)) # I'm informed this is similar to Django's prefetch_related</code>
</pre>
<pre class="language-sql"><code>-- Both at point A!
SELECT ...
FROM user
WHERE user.name = ?
SELECT ...
FROM user
JOIN basket ON user.user_id = basket.user_id
WHERE user.user_id IN (?, ?) -- The ids we SELECT-ed above earlier
-- SQLAlchemy "joins" the results together in memory</code>
</pre>
<br>
<pre class="language-python"><code>.options(raiseload(User.baskets))
# At point B, raises an error, no second query performed</code>
</pre>
<br>
<pre class="language-python"><code>.options(noload(User.baskets))
# At point B, no second query performed
# user.baskets is just an empty list</code>
</pre>
</body>
</html>