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 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398
|
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN"
"http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd">
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
<title>
SqlSoup
— SQLAlchemy 0.6.3 Documentation</title>
<link rel="stylesheet" href="../../_static/pygments.css" type="text/css" />
<link rel="stylesheet" href="../../_static/docs.css" type="text/css" />
<script type="text/javascript">
var DOCUMENTATION_OPTIONS = {
URL_ROOT: '../../',
VERSION: '0.6.3',
COLLAPSE_MODINDEX: false,
FILE_SUFFIX: '.html'
};
</script>
<script type="text/javascript" src="../../_static/jquery.js"></script>
<script type="text/javascript" src="../../_static/underscore.js"></script>
<script type="text/javascript" src="../../_static/doctools.js"></script>
<script type="text/javascript" src="../../_static/init.js"></script>
<link rel="index" title="Index" href="../../genindex.html" />
<link rel="search" title="Search" href="../../search.html" />
<link rel="top" title="SQLAlchemy 0.6.3 Documentation" href="../../index.html" />
<link rel="up" title="sqlalchemy.ext" href="index.html" />
<link rel="next" title="compiler" href="compiler.html" />
<link rel="prev" title="serializer" href="serializer.html" />
</head>
<body>
<h1>SQLAlchemy 0.6.3 Documentation</h1>
<div id="search">
Search:
<form class="search" action="../../search.html" method="get">
<input type="text" name="q" size="18" /> <input type="submit" value="Search" />
<input type="hidden" name="check_keywords" value="yes" />
<input type="hidden" name="area" value="default" />
</form>
</div>
<div class="versionheader">
Version: <span class="versionnum">0.6.3</span> Last Updated: 07/15/2010 12:35:47
</div>
<div class="clearboth"></div>
<div class="topnav">
<div id="pagecontrol">
<a href="../index.html">API Reference</a>
|
<a href="../../genindex.html">Index</a>
<div class="sourcelink">(<a href="../../_sources/reference/ext/sqlsoup.txt">view source)</div>
</div>
<div class="navbanner">
<a class="totoc" href="../../index.html">Table of Contents</a>
» <a href="../index.html" title="API Reference">API Reference</a>
» <a href="index.html" title="sqlalchemy.ext">sqlalchemy.ext</a>
»
SqlSoup
<div class="prevnext">
Previous:
<a href="serializer.html" title="previous chapter">serializer</a>
Next:
<a href="compiler.html" title="next chapter">compiler</a>
</div>
<h2>
SqlSoup
</h2>
</div>
<ul>
<li><a class="reference internal" href="#">SqlSoup</a><ul>
<li><a class="reference internal" href="#introduction">Introduction</a></li>
<li><a class="reference internal" href="#loading-objects">Loading objects</a><ul>
<li><a class="reference internal" href="#full-query-documentation">Full query documentation</a></li>
</ul>
</li>
<li><a class="reference internal" href="#modifying-objects">Modifying objects</a></li>
<li><a class="reference internal" href="#joins">Joins</a></li>
<li><a class="reference internal" href="#relationships">Relationships</a></li>
<li><a class="reference internal" href="#advanced-use">Advanced Use</a><ul>
<li><a class="reference internal" href="#sessions-transations-and-application-integration">Sessions, Transations and Application Integration</a></li>
<li><a class="reference internal" href="#mapping-arbitrary-selectables">Mapping arbitrary Selectables</a></li>
<li><a class="reference internal" href="#raw-sql">Raw SQL</a></li>
<li><a class="reference internal" href="#dynamic-table-names">Dynamic table names</a></li>
</ul>
</li>
</ul>
</li>
</ul>
<div class="clearboth"></div>
</div>
<div class="document">
<div class="body">
<div class="section" id="module-sqlalchemy.ext.sqlsoup">
<span id="sqlsoup"></span><h1>SqlSoup<a class="headerlink" href="#module-sqlalchemy.ext.sqlsoup" title="Permalink to this headline">¶</a></h1>
<div class="section" id="introduction">
<h2>Introduction<a class="headerlink" href="#introduction" title="Permalink to this headline">¶</a></h2>
<p>SqlSoup provides a convenient way to access existing database tables without
having to declare table or mapper classes ahead of time. It is built on top of the SQLAlchemy ORM and provides a super-minimalistic interface to an existing database.</p>
<p>Suppose we have a database with users, books, and loans tables
(corresponding to the PyWebOff dataset, if you’re curious).</p>
<p>Creating a SqlSoup gateway is just like creating an SQLAlchemy
engine:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="kn">from</span> <span class="nn">sqlalchemy.ext.sqlsoup</span> <span class="kn">import</span> <span class="n">SqlSoup</span>
<span class="gp">>>> </span><span class="n">db</span> <span class="o">=</span> <span class="n">SqlSoup</span><span class="p">(</span><span class="s">'sqlite:///:memory:'</span><span class="p">)</span></pre></div>
</div>
<p>or, you can re-use an existing engine:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span> <span class="o">=</span> <span class="n">SqlSoup</span><span class="p">(</span><span class="n">engine</span><span class="p">)</span></pre></div>
</div>
<p>You can optionally specify a schema within the database for your
SqlSoup:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">schema</span> <span class="o">=</span> <span class="n">myschemaname</span></pre></div>
</div>
</div>
<div class="section" id="loading-objects">
<h2>Loading objects<a class="headerlink" href="#loading-objects" title="Permalink to this headline">¶</a></h2>
<p>Loading objects is as easy as this:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">users</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">all</span><span class="p">()</span>
<span class="gp">>>> </span><span class="n">users</span><span class="o">.</span><span class="n">sort</span><span class="p">()</span>
<span class="gp">>>> </span><span class="n">users</span>
<span class="go">[MappedUsers(name=u'Joe Student',email=u'student@example.edu',password=u'student',classname=None,admin=0), MappedUsers(name=u'Bhargan Basepair',email=u'basepair@example.edu',password=u'basepair',classname=None,admin=1)]</span></pre></div>
</div>
<p>Of course, letting the database do the sort is better:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">order_by</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">name</span><span class="p">)</span><span class="o">.</span><span class="n">all</span><span class="p">()</span>
<span class="go">[MappedUsers(name=u'Bhargan Basepair',email=u'basepair@example.edu',password=u'basepair',classname=None,admin=1), MappedUsers(name=u'Joe Student',email=u'student@example.edu',password=u'student',classname=None,admin=0)]</span></pre></div>
</div>
<p>Field access is intuitive:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">users</span><span class="p">[</span><span class="mi">0</span><span class="p">]</span><span class="o">.</span><span class="n">email</span>
<span class="go">u'student@example.edu'</span></pre></div>
</div>
<p>Of course, you don’t want to load all users very often. Let’s add a
WHERE clause. Let’s also switch the order_by to DESC while we’re at
it:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="kn">from</span> <span class="nn">sqlalchemy</span> <span class="kn">import</span> <span class="n">or_</span><span class="p">,</span> <span class="n">and_</span><span class="p">,</span> <span class="n">desc</span>
<span class="gp">>>> </span><span class="n">where</span> <span class="o">=</span> <span class="n">or_</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">name</span><span class="o">==</span><span class="s">'Bhargan Basepair'</span><span class="p">,</span> <span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">email</span><span class="o">==</span><span class="s">'student@example.edu'</span><span class="p">)</span>
<span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">filter</span><span class="p">(</span><span class="n">where</span><span class="p">)</span><span class="o">.</span><span class="n">order_by</span><span class="p">(</span><span class="n">desc</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">name</span><span class="p">))</span><span class="o">.</span><span class="n">all</span><span class="p">()</span>
<span class="go">[MappedUsers(name=u'Joe Student',email=u'student@example.edu',password=u'student',classname=None,admin=0), MappedUsers(name=u'Bhargan Basepair',email=u'basepair@example.edu',password=u'basepair',classname=None,admin=1)]</span></pre></div>
</div>
<p>You can also use .first() (to retrieve only the first object from a query) or
.one() (like .first when you expect exactly one user – it will raise an
exception if more were returned):</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">filter</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">name</span><span class="o">==</span><span class="s">'Bhargan Basepair'</span><span class="p">)</span><span class="o">.</span><span class="n">one</span><span class="p">()</span>
<span class="go">MappedUsers(name=u'Bhargan Basepair',email=u'basepair@example.edu',password=u'basepair',classname=None,admin=1)</span></pre></div>
</div>
<p>Since name is the primary key, this is equivalent to</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">get</span><span class="p">(</span><span class="s">'Bhargan Basepair'</span><span class="p">)</span>
<span class="go">MappedUsers(name=u'Bhargan Basepair',email=u'basepair@example.edu',password=u'basepair',classname=None,admin=1)</span></pre></div>
</div>
<p>This is also equivalent to</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">filter_by</span><span class="p">(</span><span class="n">name</span><span class="o">=</span><span class="s">'Bhargan Basepair'</span><span class="p">)</span><span class="o">.</span><span class="n">one</span><span class="p">()</span>
<span class="go">MappedUsers(name=u'Bhargan Basepair',email=u'basepair@example.edu',password=u'basepair',classname=None,admin=1)</span></pre></div>
</div>
<p>filter_by is like filter, but takes kwargs instead of full clause expressions.
This makes it more concise for simple queries like this, but you can’t do
complex queries like the or_ above or non-equality based comparisons this way.</p>
<div class="section" id="full-query-documentation">
<h3>Full query documentation<a class="headerlink" href="#full-query-documentation" title="Permalink to this headline">¶</a></h3>
<p>Get, filter, filter_by, order_by, limit, and the rest of the
query methods are explained in detail in <a class="reference internal" href="../../ormtutorial.html#ormtutorial-querying"><em>Querying</em></a>.</p>
</div>
</div>
<div class="section" id="modifying-objects">
<h2>Modifying objects<a class="headerlink" href="#modifying-objects" title="Permalink to this headline">¶</a></h2>
<p>Modifying objects is intuitive:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">user</span> <span class="o">=</span> <span class="n">_</span>
<span class="gp">>>> </span><span class="n">user</span><span class="o">.</span><span class="n">email</span> <span class="o">=</span> <span class="s">'basepair+nospam@example.edu'</span>
<span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">commit</span><span class="p">()</span></pre></div>
</div>
<p>(SqlSoup leverages the sophisticated SQLAlchemy unit-of-work code, so
multiple updates to a single object will be turned into a single
<tt class="docutils literal"><span class="pre">UPDATE</span></tt> statement when you commit.)</p>
<p>To finish covering the basics, let’s insert a new loan, then delete
it:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">book_id</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">books</span><span class="o">.</span><span class="n">filter_by</span><span class="p">(</span><span class="n">title</span><span class="o">=</span><span class="s">'Regional Variation in Moss'</span><span class="p">)</span><span class="o">.</span><span class="n">first</span><span class="p">()</span><span class="o">.</span><span class="n">id</span>
<span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">insert</span><span class="p">(</span><span class="n">book_id</span><span class="o">=</span><span class="n">book_id</span><span class="p">,</span> <span class="n">user_name</span><span class="o">=</span><span class="n">user</span><span class="o">.</span><span class="n">name</span><span class="p">)</span>
<span class="go">MappedLoans(book_id=2,user_name=u'Bhargan Basepair',loan_date=None)</span>
<span class="gp">>>> </span><span class="n">loan</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">filter_by</span><span class="p">(</span><span class="n">book_id</span><span class="o">=</span><span class="mi">2</span><span class="p">,</span> <span class="n">user_name</span><span class="o">=</span><span class="s">'Bhargan Basepair'</span><span class="p">)</span><span class="o">.</span><span class="n">one</span><span class="p">()</span>
<span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">delete</span><span class="p">(</span><span class="n">loan</span><span class="p">)</span>
<span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">commit</span><span class="p">()</span></pre></div>
</div>
<p>You can also delete rows that have not been loaded as objects. Let’s
do our insert/delete cycle once more, this time using the loans
table’s delete method. (For SQLAlchemy experts: note that no flush()
call is required since this delete acts at the SQL level, not at the
Mapper level.) The same where-clause construction rules apply here as
to the select methods.</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">insert</span><span class="p">(</span><span class="n">book_id</span><span class="o">=</span><span class="n">book_id</span><span class="p">,</span> <span class="n">user_name</span><span class="o">=</span><span class="n">user</span><span class="o">.</span><span class="n">name</span><span class="p">)</span>
<span class="go">MappedLoans(book_id=2,user_name=u'Bhargan Basepair',loan_date=None)</span>
<span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">delete</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">book_id</span><span class="o">==</span><span class="mi">2</span><span class="p">)</span></pre></div>
</div>
<p>You can similarly update multiple rows at once. This will change the
book_id to 1 in all loans whose book_id is 2:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">update</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">book_id</span><span class="o">==</span><span class="mi">2</span><span class="p">,</span> <span class="n">book_id</span><span class="o">=</span><span class="mi">1</span><span class="p">)</span>
<span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">filter_by</span><span class="p">(</span><span class="n">book_id</span><span class="o">=</span><span class="mi">1</span><span class="p">)</span><span class="o">.</span><span class="n">all</span><span class="p">()</span>
<span class="go">[MappedLoans(book_id=1,user_name=u'Joe Student',loan_date=datetime.datetime(2006, 7, 12, 0, 0))]</span></pre></div>
</div>
</div>
<div class="section" id="joins">
<h2>Joins<a class="headerlink" href="#joins" title="Permalink to this headline">¶</a></h2>
<p>Occasionally, you will want to pull out a lot of data from related
tables all at once. In this situation, it is far more efficient to
have the database perform the necessary join. (Here we do not have <em>a
lot of data</em> but hopefully the concept is still clear.) SQLAlchemy is
smart enough to recognize that loans has a foreign key to users, and
uses that as the join condition automatically.</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">join1</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">join</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="p">,</span> <span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="p">,</span> <span class="n">isouter</span><span class="o">=</span><span class="bp">True</span><span class="p">)</span>
<span class="gp">>>> </span><span class="n">join1</span><span class="o">.</span><span class="n">filter_by</span><span class="p">(</span><span class="n">name</span><span class="o">=</span><span class="s">'Joe Student'</span><span class="p">)</span><span class="o">.</span><span class="n">all</span><span class="p">()</span>
<span class="go">[MappedJoin(name=u'Joe Student',email=u'student@example.edu',password=u'student',classname=None,admin=0,book_id=1,user_name=u'Joe Student',loan_date=datetime.datetime(2006, 7, 12, 0, 0))]</span></pre></div>
</div>
<p>If you’re unfortunate enough to be using MySQL with the default MyISAM
storage engine, you’ll have to specify the join condition manually,
since MyISAM does not store foreign keys. Here’s the same join again,
with the join condition explicitly specified:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">join</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="p">,</span> <span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="p">,</span> <span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">name</span><span class="o">==</span><span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">user_name</span><span class="p">,</span> <span class="n">isouter</span><span class="o">=</span><span class="bp">True</span><span class="p">)</span>
<span class="go"><class 'sqlalchemy.ext.sqlsoup.MappedJoin'></span></pre></div>
</div>
<p>You can compose arbitrarily complex joins by combining Join objects
with tables or other joins. Here we combine our first join with the
books table:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">join2</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">join</span><span class="p">(</span><span class="n">join1</span><span class="p">,</span> <span class="n">db</span><span class="o">.</span><span class="n">books</span><span class="p">)</span>
<span class="gp">>>> </span><span class="n">join2</span><span class="o">.</span><span class="n">all</span><span class="p">()</span>
<span class="go">[MappedJoin(name=u'Joe Student',email=u'student@example.edu',password=u'student',classname=None,admin=0,book_id=1,user_name=u'Joe Student',loan_date=datetime.datetime(2006, 7, 12, 0, 0),id=1,title=u'Mustards I Have Known',published_year=u'1989',authors=u'Jones')]</span></pre></div>
</div>
<p>If you join tables that have an identical column name, wrap your join
with <cite>with_labels</cite>, to disambiguate columns with their table name
(.c is short for .columns):</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">with_labels</span><span class="p">(</span><span class="n">join1</span><span class="p">)</span><span class="o">.</span><span class="n">c</span><span class="o">.</span><span class="n">keys</span><span class="p">()</span>
<span class="go">[u'users_name', u'users_email', u'users_password', u'users_classname', u'users_admin', u'loans_book_id', u'loans_user_name', u'loans_loan_date']</span></pre></div>
</div>
<p>You can also join directly to a labeled object:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">labeled_loans</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">with_labels</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="p">)</span>
<span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">join</span><span class="p">(</span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="p">,</span> <span class="n">labeled_loans</span><span class="p">,</span> <span class="n">isouter</span><span class="o">=</span><span class="bp">True</span><span class="p">)</span><span class="o">.</span><span class="n">c</span><span class="o">.</span><span class="n">keys</span><span class="p">()</span>
<span class="go">[u'name', u'email', u'password', u'classname', u'admin', u'loans_book_id', u'loans_user_name', u'loans_loan_date']</span></pre></div>
</div>
</div>
<div class="section" id="relationships">
<h2>Relationships<a class="headerlink" href="#relationships" title="Permalink to this headline">¶</a></h2>
<p>You can define relationships on SqlSoup classes:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">relate</span><span class="p">(</span><span class="s">'loans'</span><span class="p">,</span> <span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="p">)</span></pre></div>
</div>
<p>These can then be used like a normal SA property:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">get</span><span class="p">(</span><span class="s">'Joe Student'</span><span class="p">)</span><span class="o">.</span><span class="n">loans</span>
<span class="go">[MappedLoans(book_id=1,user_name=u'Joe Student',loan_date=datetime.datetime(2006, 7, 12, 0, 0))]</span></pre></div>
</div>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">filter</span><span class="p">(</span><span class="o">~</span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">any</span><span class="p">())</span><span class="o">.</span><span class="n">all</span><span class="p">()</span>
<span class="go">[MappedUsers(name=u'Bhargan Basepair',email='basepair+nospam@example.edu',password=u'basepair',classname=None,admin=1)]</span></pre></div>
</div>
<p>relate can take any options that the relationship function accepts in normal mapper definition:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="k">del</span> <span class="n">db</span><span class="o">.</span><span class="n">_cache</span><span class="p">[</span><span class="s">'users'</span><span class="p">]</span>
<span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">users</span><span class="o">.</span><span class="n">relate</span><span class="p">(</span><span class="s">'loans'</span><span class="p">,</span> <span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="p">,</span> <span class="n">order_by</span><span class="o">=</span><span class="n">db</span><span class="o">.</span><span class="n">loans</span><span class="o">.</span><span class="n">loan_date</span><span class="p">,</span> <span class="n">cascade</span><span class="o">=</span><span class="s">'all, delete-orphan'</span><span class="p">)</span></pre></div>
</div>
</div>
<div class="section" id="advanced-use">
<h2>Advanced Use<a class="headerlink" href="#advanced-use" title="Permalink to this headline">¶</a></h2>
<div class="section" id="sessions-transations-and-application-integration">
<h3>Sessions, Transations and Application Integration<a class="headerlink" href="#sessions-transations-and-application-integration" title="Permalink to this headline">¶</a></h3>
<p><strong>Note:</strong> please read and understand this section thoroughly before using SqlSoup in any web application.</p>
<p>SqlSoup uses a ScopedSession to provide thread-local sessions. You
can get a reference to the current one like this:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">session</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">session</span></pre></div>
</div>
<p>The default session is available at the module level in SQLSoup, via:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="kn">from</span> <span class="nn">sqlalchemy.ext.sqlsoup</span> <span class="kn">import</span> <span class="n">Session</span></pre></div>
</div>
<p>The configuration of this session is <tt class="docutils literal"><span class="pre">autoflush=True</span></tt>, <tt class="docutils literal"><span class="pre">autocommit=False</span></tt>.
This means when you work with the SqlSoup object, you need to call <tt class="docutils literal"><span class="pre">db.commit()</span></tt>
in order to have changes persisted. You may also call <tt class="docutils literal"><span class="pre">db.rollback()</span></tt> to
roll things back.</p>
<p>Since the SqlSoup object’s Session automatically enters into a transaction as soon
as it’s used, it is <em>essential</em> that you call <tt class="docutils literal"><span class="pre">commit()</span></tt> or <tt class="docutils literal"><span class="pre">rollback()</span></tt>
on it when the work within a thread completes. This means all the guidelines
for web application integration at <a class="reference internal" href="../../session.html#session-lifespan"><em>Lifespan of a Contextual Session</em></a> must be followed.</p>
<p>The SqlSoup object can have any session or scoped session configured onto it.
This is of key importance when integrating with existing code or frameworks
such as Pylons. If your application already has a <tt class="docutils literal"><span class="pre">Session</span></tt> configured,
pass it to your SqlSoup object:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="kn">from</span> <span class="nn">myapplication</span> <span class="kn">import</span> <span class="n">Session</span>
<span class="gp">>>> </span><span class="n">db</span> <span class="o">=</span> <span class="n">SqlSoup</span><span class="p">(</span><span class="n">session</span><span class="o">=</span><span class="n">Session</span><span class="p">)</span></pre></div>
</div>
<p>If the <tt class="docutils literal"><span class="pre">Session</span></tt> is configured with <tt class="docutils literal"><span class="pre">autocommit=True</span></tt>, use <tt class="docutils literal"><span class="pre">flush()</span></tt>
instead of <tt class="docutils literal"><span class="pre">commit()</span></tt> to persist changes - in this case, the <tt class="docutils literal"><span class="pre">Session</span></tt>
closes out its transaction immediately and no external management is needed. <tt class="docutils literal"><span class="pre">rollback()</span></tt> is also not available. Configuring a new SQLSoup object in “autocommit” mode looks like:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="kn">from</span> <span class="nn">sqlalchemy.orm</span> <span class="kn">import</span> <span class="n">scoped_session</span><span class="p">,</span> <span class="n">sessionmaker</span>
<span class="gp">>>> </span><span class="n">db</span> <span class="o">=</span> <span class="n">SqlSoup</span><span class="p">(</span><span class="s">'sqlite://'</span><span class="p">,</span> <span class="n">session</span><span class="o">=</span><span class="n">scoped_session</span><span class="p">(</span><span class="n">sessionmaker</span><span class="p">(</span><span class="n">autoflush</span><span class="o">=</span><span class="bp">False</span><span class="p">,</span> <span class="n">expire_on_commit</span><span class="o">=</span><span class="bp">False</span><span class="p">,</span> <span class="n">autocommit</span><span class="o">=</span><span class="bp">True</span><span class="p">)))</span></pre></div>
</div>
</div>
<div class="section" id="mapping-arbitrary-selectables">
<h3>Mapping arbitrary Selectables<a class="headerlink" href="#mapping-arbitrary-selectables" title="Permalink to this headline">¶</a></h3>
<p>SqlSoup can map any SQLAlchemy <tt class="docutils literal"><span class="pre">Selectable</span></tt> with the map
method. Let’s map a <tt class="docutils literal"><span class="pre">Select</span></tt> object that uses an aggregate function;
we’ll use the SQLAlchemy <tt class="docutils literal"><span class="pre">Table</span></tt> that SqlSoup introspected as the
basis. (Since we’re not mapping to a simple table or join, we need to
tell SQLAlchemy how to find the <em>primary key</em> which just needs to be
unique within the select, and not necessarily correspond to a <em>real</em>
PK in the database.)</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="kn">from</span> <span class="nn">sqlalchemy</span> <span class="kn">import</span> <span class="n">select</span><span class="p">,</span> <span class="n">func</span>
<span class="gp">>>> </span><span class="n">b</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">books</span><span class="o">.</span><span class="n">_table</span>
<span class="gp">>>> </span><span class="n">s</span> <span class="o">=</span> <span class="n">select</span><span class="p">([</span><span class="n">b</span><span class="o">.</span><span class="n">c</span><span class="o">.</span><span class="n">published_year</span><span class="p">,</span> <span class="n">func</span><span class="o">.</span><span class="n">count</span><span class="p">(</span><span class="s">'*'</span><span class="p">)</span><span class="o">.</span><span class="n">label</span><span class="p">(</span><span class="s">'n'</span><span class="p">)],</span> <span class="n">from_obj</span><span class="o">=</span><span class="p">[</span><span class="n">b</span><span class="p">],</span> <span class="n">group_by</span><span class="o">=</span><span class="p">[</span><span class="n">b</span><span class="o">.</span><span class="n">c</span><span class="o">.</span><span class="n">published_year</span><span class="p">])</span>
<span class="gp">>>> </span><span class="n">s</span> <span class="o">=</span> <span class="n">s</span><span class="o">.</span><span class="n">alias</span><span class="p">(</span><span class="s">'years_with_count'</span><span class="p">)</span>
<span class="gp">>>> </span><span class="n">years_with_count</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">map</span><span class="p">(</span><span class="n">s</span><span class="p">,</span> <span class="n">primary_key</span><span class="o">=</span><span class="p">[</span><span class="n">s</span><span class="o">.</span><span class="n">c</span><span class="o">.</span><span class="n">published_year</span><span class="p">])</span>
<span class="gp">>>> </span><span class="n">years_with_count</span><span class="o">.</span><span class="n">filter_by</span><span class="p">(</span><span class="n">published_year</span><span class="o">=</span><span class="s">'1989'</span><span class="p">)</span><span class="o">.</span><span class="n">all</span><span class="p">()</span>
<span class="go">[MappedBooks(published_year=u'1989',n=1)]</span></pre></div>
</div>
<p>Obviously if we just wanted to get a list of counts associated with
book years once, raw SQL is going to be less work. The advantage of
mapping a Select is reusability, both standalone and in Joins. (And if
you go to full SQLAlchemy, you can perform mappings like this directly
to your object models.)</p>
<p>An easy way to save mapped selectables like this is to just hang them on
your db object:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">years_with_count</span> <span class="o">=</span> <span class="n">years_with_count</span></pre></div>
</div>
<p>Python is flexible like that!</p>
</div>
<div class="section" id="raw-sql">
<h3>Raw SQL<a class="headerlink" href="#raw-sql" title="Permalink to this headline">¶</a></h3>
<p>SqlSoup works fine with SQLAlchemy’s text construct, described in <a class="reference internal" href="../../sqlexpression.html#sqlexpression-text"><em>Using Text</em></a>.
You can also execute textual SQL directly using the <cite>execute()</cite> method,
which corresponds to the <cite>execute()</cite> method on the underlying <cite>Session</cite>.
Expressions here are expressed like <tt class="docutils literal"><span class="pre">text()</span></tt> constructs, using named parameters
with colons:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">rp</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s">'select name, email from users where name like :name order by name'</span><span class="p">,</span> <span class="n">name</span><span class="o">=</span><span class="s">'%Bhargan%'</span><span class="p">)</span>
<span class="gp">>>> </span><span class="k">for</span> <span class="n">name</span><span class="p">,</span> <span class="n">email</span> <span class="ow">in</span> <span class="n">rp</span><span class="o">.</span><span class="n">fetchall</span><span class="p">():</span> <span class="k">print</span> <span class="n">name</span><span class="p">,</span> <span class="n">email</span>
<span class="go">Bhargan Basepair basepair+nospam@example.edu</span></pre></div>
</div>
<p>Or you can get at the current transaction’s connection using <cite>connection()</cite>. This is the
raw connection object which can accept any sort of SQL expression or raw SQL string passed to the database:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">conn</span> <span class="o">=</span> <span class="n">db</span><span class="o">.</span><span class="n">connection</span><span class="p">()</span>
<span class="gp">>>> </span><span class="n">conn</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s">"'select name, email from users where name like ? order by name'"</span><span class="p">,</span> <span class="s">'%Bhargan%'</span><span class="p">)</span></pre></div>
</div>
</div>
<div class="section" id="dynamic-table-names">
<h3>Dynamic table names<a class="headerlink" href="#dynamic-table-names" title="Permalink to this headline">¶</a></h3>
<p>You can load a table whose name is specified at runtime with the entity() method:</p>
<div class="highlight-python"><div class="highlight"><pre><span class="gp">>>> </span><span class="n">tablename</span> <span class="o">=</span> <span class="s">'loans'</span>
<span class="gp">>>> </span><span class="n">db</span><span class="o">.</span><span class="n">entity</span><span class="p">(</span><span class="n">tablename</span><span class="p">)</span> <span class="o">==</span> <span class="n">db</span><span class="o">.</span><span class="n">loans</span>
<span class="go">True</span></pre></div>
</div>
<p>entity() also takes an optional schema argument. If none is specified, the
default schema is used.</p>
</div>
</div>
</div>
</div>
</div>
<div class="bottomnav">
<div class="prevnext">
Previous:
<a href="serializer.html" title="previous chapter">serializer</a>
Next:
<a href="compiler.html" title="next chapter">compiler</a>
</div>
<div class="doc_copyright">
© Copyright 2007, 2008, 2009, 2010, the SQLAlchemy authors and contributors.
Created using <a href="http://sphinx.pocoo.org/">Sphinx</a> 1.0b2+.
</div>
</div>
</body>
</html>
|