File: tips.html

package info (click to toggle)
python-apsw 3.46.0.1-1
  • links: PTS
  • area: main
  • in suites: forky, sid, trixie
  • size: 9,684 kB
  • sloc: python: 13,125; ansic: 12,334; javascript: 911; makefile: 10; sh: 7
file content (420 lines) | stat: -rw-r--r-- 34,627 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
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
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
<!DOCTYPE html>
<html class="writer-html5" lang="en" data-content_root="./">
<head>
  <meta charset="utf-8" /><meta name="viewport" content="width=device-width, initial-scale=1" />

  <meta name="viewport" content="width=device-width, initial-scale=1.0" />
  <title>Tips &mdash; APSW 3.46.0.1 documentation</title>
      <link rel="stylesheet" type="text/css" href="_static/pygments.css?v=72bcf2f2" />
      <link rel="stylesheet" type="text/css" href="_static/css/theme.css?v=19f00094" />
      <link rel="stylesheet" type="text/css" href="_static/apsw.css?v=3c7e2631" />

  
    <link rel="shortcut icon" href="_static/favicon.ico"/>
  <!--[if lt IE 9]>
    <script src="_static/js/html5shiv.min.js"></script>
  <![endif]-->
  
        <script src="_static/jquery.js?v=5d32c60e"></script>
        <script src="_static/_sphinx_javascript_frameworks_compat.js?v=2cd50e6c"></script>
        <script src="_static/documentation_options.js?v=d98f5d2b"></script>
        <script src="_static/doctools.js?v=9a2dae69"></script>
        <script src="_static/sphinx_highlight.js?v=dc90522c"></script>
    <script src="_static/js/theme.js"></script>
    <link rel="author" title="About these documents" href="about.html" />
    <link rel="index" title="Index" href="genindex.html" />
    <link rel="search" title="Search" href="search.html" />
    <link rel="copyright" title="Copyright" href="copyright.html" />
    <link rel="next" title="Example/Tour" href="example.html" />
    <link rel="prev" title="About" href="about.html" /> 
</head>

<body class="wy-body-for-nav"> 
  <div class="wy-grid-for-nav">
    <nav data-toggle="wy-nav-shift" class="wy-nav-side">
      <div class="wy-side-scroll">
        <div class="wy-side-nav-search" >

          
          
          <a href="index.html" class="icon icon-home">
            APSW
              <img src="_static/apswlogo.png" class="logo" alt="Logo"/>
          </a>
              <div class="version">
                3.46.0.1
              </div>
<div role="search">
  <form id="rtd-search-form" class="wy-form" action="search.html" method="get">
    <input type="text" name="q" placeholder="Search docs" aria-label="Search docs" />
    <input type="hidden" name="check_keywords" value="yes" />
    <input type="hidden" name="area" value="default" />
  </form>
</div>
        </div><div class="wy-menu wy-menu-vertical" data-spy="affix" role="navigation" aria-label="Navigation menu">
              <ul class="current">
<li class="toctree-l1"><a class="reference internal" href="about.html">About</a></li>
<li class="toctree-l1 current"><a class="current reference internal" href="#">Tips</a><ul>
<li class="toctree-l2"><a class="reference internal" href="#sqlite-is-different">SQLite is different</a></li>
<li class="toctree-l2"><a class="reference internal" href="#types">Types</a></li>
<li class="toctree-l2"><a class="reference internal" href="#transactions">Transactions</a></li>
<li class="toctree-l2"><a class="reference internal" href="#queries">Queries</a></li>
<li class="toctree-l2"><a class="reference internal" href="#bindings">Bindings</a></li>
<li class="toctree-l2"><a class="reference internal" href="#diagnostics">Diagnostics</a></li>
<li class="toctree-l2"><a class="reference internal" href="#managing-and-updating-your-schema">Managing and updating your schema</a></li>
<li class="toctree-l2"><a class="reference internal" href="#parsing-sql">Parsing SQL</a></li>
<li class="toctree-l2"><a class="reference internal" href="#busy-handling">Busy handling</a></li>
<li class="toctree-l2"><a class="reference internal" href="#database-schema">Database schema</a></li>
<li class="toctree-l2"><a class="reference internal" href="#write-ahead-logging">Write Ahead Logging</a></li>
<li class="toctree-l2"><a class="reference internal" href="#customizing-connections">Customizing Connections</a></li>
<li class="toctree-l2"><a class="reference internal" href="#customizing-cursors">Customizing Cursors</a></li>
</ul>
</li>
<li class="toctree-l1"><a class="reference internal" href="example.html">Example/Tour</a></li>
<li class="toctree-l1"><a class="reference internal" href="install.html">Installation and customization</a></li>
<li class="toctree-l1"><a class="reference internal" href="extensions.html">Extensions</a></li>
<li class="toctree-l1"><a class="reference internal" href="apsw.html">APSW Module</a></li>
<li class="toctree-l1"><a class="reference internal" href="connection.html">Connections to a database</a></li>
<li class="toctree-l1"><a class="reference internal" href="cursor.html">Cursors (executing SQL)</a></li>
<li class="toctree-l1"><a class="reference internal" href="blob.html">Blob Input/Output</a></li>
<li class="toctree-l1"><a class="reference internal" href="backup.html">Backup</a></li>
<li class="toctree-l1"><a class="reference internal" href="vtable.html">Virtual Tables</a></li>
<li class="toctree-l1"><a class="reference internal" href="vfs.html">Virtual File System (VFS)</a></li>
<li class="toctree-l1"><a class="reference internal" href="shell.html">Shell</a></li>
<li class="toctree-l1"><a class="reference internal" href="bestpractice.html">Best Practice</a></li>
<li class="toctree-l1"><a class="reference internal" href="ext.html">Various interesting and useful bits of functionality</a></li>
<li class="toctree-l1"><a class="reference internal" href="exceptions.html">Exceptions and Errors</a></li>
<li class="toctree-l1"><a class="reference internal" href="execution.html">Execution and tracing</a></li>
<li class="toctree-l1"><a class="reference internal" href="dbapi.html">DBAPI notes</a></li>
<li class="toctree-l1"><a class="reference internal" href="pysqlite.html">sqlite3 module differences</a></li>
<li class="toctree-l1"><a class="reference internal" href="benchmarking.html">Benchmarking</a></li>
<li class="toctree-l1"><a class="reference internal" href="copyright.html">Copyright and License</a></li>
<li class="toctree-l1"><a class="reference internal" href="changes.html">Change History</a></li>
<li class="toctree-l1"><a class="reference internal" href="py-modindex.html">Module Index</a></li>
<li class="toctree-l1"><a class="reference internal" href="genindex.html">Index</a></li>
</ul>

        </div>
      </div>
    </nav>

    <section data-toggle="wy-nav-shift" class="wy-nav-content-wrap"><nav class="wy-nav-top" aria-label="Mobile navigation menu" >
          <i data-toggle="wy-nav-top" class="fa fa-bars"></i>
          <a href="index.html">APSW</a>
      </nav>

      <div class="wy-nav-content">
        <div class="rst-content style-external-links">
          <div role="navigation" aria-label="Page navigation">
  <ul class="wy-breadcrumbs">
      <li><a href="index.html" class="icon icon-home" aria-label="Home"></a></li>
      <li class="breadcrumb-item active">Tips</li>
      <li class="wy-breadcrumbs-aside">
            <a href="_sources/tips.rst.txt" rel="nofollow"> View page source</a>
      </li>
  </ul><div class="rst-breadcrumbs-buttons" role="navigation" aria-label="Sequential page navigation">
        <a href="about.html" class="btn btn-neutral float-left" title="About" accesskey="p"><span class="fa fa-arrow-circle-left" aria-hidden="true"></span> Previous</a>
        <a href="example.html" class="btn btn-neutral float-right" title="Example/Tour" accesskey="n">Next <span class="fa fa-arrow-circle-right" aria-hidden="true"></span></a>
  </div>
  <hr/>
</div>
          <div role="main" class="document" itemscope="itemscope" itemtype="http://schema.org/Article">
           <div itemprop="articleBody">
             
  <section id="tips">
<h1>Tips<a class="headerlink" href="#tips" title="Link to this heading"></a></h1>
<p>There are also specific tips in each documentation section, and many of the
classes, functions, and attributes.</p>
<section id="sqlite-is-different">
<h2>SQLite is different<a class="headerlink" href="#sqlite-is-different" title="Link to this heading"></a></h2>
<p>While SQLite provides a SQL database like many others out there, it is
also unique in many ways.  Read about the unique features at the
<a class="reference external" href="https://sqlite.org/different.html">SQLite website</a> and <a class="reference external" href="https://www.sqlite.org/quirks.html">quirks</a>.</p>
<div class="admonition tip">
<p class="admonition-title">Tip</p>
<p>Using <a class="reference internal" href="bestpractice.html"><span class="doc">APSW best practice</span></a> is recommended to get
best performance and avoid common mistakes.</p>
</div>
</section>
<section id="types">
<span id="id1"></span><h2>Types<a class="headerlink" href="#types" title="Link to this heading"></a></h2>
<p>SQLite has <a class="reference external" href="https://www.sqlite.org/datatype3.html">5 storage types</a>.</p>
<table class="docutils align-default">
<thead>
<tr class="row-odd"><th class="head"><p>SQLite</p></th>
<th class="head"><p>Python</p></th>
</tr>
</thead>
<tbody>
<tr class="row-even"><td><p>NULL</p></td>
<td><p><a class="reference external" href="https://docs.python.org/3/library/constants.html#None" title="(in Python v3.12)"><code class="xref py py-data docutils literal notranslate"><span class="pre">None</span></code></a></p></td>
</tr>
<tr class="row-odd"><td><p>Text (limit 1GB when encoded as bytes)</p></td>
<td><p><a class="reference external" href="https://docs.python.org/3/library/stdtypes.html#str" title="(in Python v3.12)"><code class="xref py py-class docutils literal notranslate"><span class="pre">str</span></code></a></p></td>
</tr>
<tr class="row-even"><td><p>Integer (Signed 64 bit)</p></td>
<td><p><a class="reference external" href="https://docs.python.org/3/library/functions.html#int" title="(in Python v3.12)"><code class="xref py py-class docutils literal notranslate"><span class="pre">int</span></code></a></p></td>
</tr>
<tr class="row-odd"><td><p>Float (<a class="reference external" href="https://en.wikipedia.org/wiki/Double-precision_floating-point_format">IEEE754 64 bit</a>)</p></td>
<td><p><a class="reference external" href="https://docs.python.org/3/library/functions.html#float" title="(in Python v3.12)"><code class="xref py py-class docutils literal notranslate"><span class="pre">float</span></code></a></p></td>
</tr>
<tr class="row-even"><td><p><a class="reference external" href="https://en.wikipedia.org/wiki/Binary_large_object">BLOB</a> (binary data, limit 1GB)</p></td>
<td><p><a class="reference external" href="https://docs.python.org/3/library/stdtypes.html#bytes" title="(in Python v3.12)"><code class="xref py py-class docutils literal notranslate"><span class="pre">bytes</span></code></a> and similar such as <a class="reference external" href="https://docs.python.org/3/library/stdtypes.html#bytearray" title="(in Python v3.12)"><code class="xref py py-class docutils literal notranslate"><span class="pre">bytearray</span></code></a> and <a class="reference external" href="https://docs.python.org/3/library/array.html#array.array" title="(in Python v3.12)"><code class="xref py py-class docutils literal notranslate"><span class="pre">array.array</span></code></a></p></td>
</tr>
</tbody>
</table>
<p><span class="target" id="index-0"></span>Dates and times do not have a dedicated storage type, but do
have a <a class="reference external" href="https://www.sqlite.org/lang_datefunc.html">variety of functions</a> for creating,
manipulating, and storing them. <span class="target" id="index-1"></span>JSON does not have a
dedicated storage type, but does have a <a class="reference external" href="https://www.sqlite.org/json1.html">variety of functions</a> for creating, manipulating, and
storing JSON.</p>
<p>APSW provides optional <a class="reference internal" href="example.html#example-type-conversion"><span class="std std-ref">type conversion</span></a>, but
the underlying storage will always be one of the 5 storage types.</p>
<p>If a column declaration gives a type then SQLite
<a class="reference external" href="https://www.sqlite.org/flextypegood.html">attempts conversion</a>.</p>
<div class="highlight-python notranslate"><div class="highlight"><pre><span></span><span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;&quot;&quot;</span>
<span class="s2">    create table types1(a, b, c, d, e);</span>
<span class="s2">    create table types2(a INTEGER, b REAL, c TEXT, d, e BLOB);</span>
<span class="s2">    &quot;&quot;&quot;</span><span class="p">)</span>

<span class="n">data</span> <span class="o">=</span> <span class="p">(</span><span class="s2">&quot;12&quot;</span><span class="p">,</span> <span class="mi">3</span><span class="p">,</span> <span class="mi">4</span><span class="p">,</span> <span class="mf">5.5</span><span class="p">,</span> <span class="sa">b</span><span class="s2">&quot;</span><span class="se">\x03\x72\xf4\x00\x9e</span><span class="s2">&quot;</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;insert into types1 values(?,?,?,?,?)&quot;</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>
<span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;insert into types2 values(?,?,?,?,?)&quot;</span><span class="p">,</span> <span class="n">data</span><span class="p">)</span>

<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;select * from types1&quot;</span><span class="p">):</span>
    <span class="nb">print</span><span class="p">(</span><span class="s2">&quot;types1&quot;</span><span class="p">,</span> <span class="nb">repr</span><span class="p">(</span><span class="n">row</span><span class="p">))</span>

<span class="k">for</span> <span class="n">row</span> <span class="ow">in</span> <span class="n">connection</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;select * from types2&quot;</span><span class="p">):</span>
    <span class="nb">print</span><span class="p">(</span><span class="s2">&quot;types2&quot;</span><span class="p">,</span> <span class="nb">repr</span><span class="p">(</span><span class="n">row</span><span class="p">))</span>
</pre></div>
</div>
<div class="highlight-output notranslate"><div class="highlight"><pre><span></span><span class="go">types1 (&#39;12&#39;, 3, 4, 5.5, b&#39;\x03r\xf4\x00\x9e&#39;)</span>
<span class="go">types2 (12, 3.0, &#39;4&#39;, 5.5, b&#39;\x03r\xf4\x00\x9e&#39;)</span>
</pre></div>
</div>
</section>
<section id="transactions">
<h2>Transactions<a class="headerlink" href="#transactions" title="Link to this heading"></a></h2>
<p>Transactions are the changes applied to a database file as a whole.
They either happen completely, or not at all.  SQLite notes all the
changes made during a transaction, and at the end when you commit will
cause them to permanently end up in the database.  If you do not
commit, or just exit, then other/new connections will not see the
changes and SQLite handles tidying up the work in progress
automatically.</p>
<p>Committing a transaction can be quite time consuming.  SQLite uses a robust
multi-step process that has to handle errors that can occur at any point,
and asks the operating system to ensure that data is on storage and would
survive a power cycle.  This will <a class="reference external" href="https://www.sqlite.org/faq.html#q19">limit the rate at which you can do
transactions</a>.</p>
<p>If you do nothing, then each statement is a single transaction:</p>
<div class="highlight-default notranslate"><div class="highlight"><pre><span></span><span class="c1"># this will be 3 separate transactions</span>
<span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;INSERT ...&quot;</span><span class="p">)</span>
<span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;INSERT ...&quot;</span><span class="p">)</span>
<span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;INSERT ...&quot;</span><span class="p">)</span>
</pre></div>
</div>
<p>You can use BEGIN/COMMIT to set the transaction boundary:</p>
<div class="highlight-default notranslate"><div class="highlight"><pre><span></span><span class="c1"># this will be one transaction</span>
<span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;BEGIN&quot;</span><span class="p">)</span>
<span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;INSERT ...&quot;</span><span class="p">)</span>
<span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;INSERT ...&quot;</span><span class="p">)</span>
<span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;INSERT ...&quot;</span><span class="p">)</span>
<span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;COMMIT&quot;</span><span class="p">)</span>
</pre></div>
</div>
<p>However that is extra effort, and also requires error handling.  For example
if the second INSERT failed then you likely want to ROLLBACK the incomplete
transaction, so that additional work on the same connection doesn’t see the
partial data.</p>
<p>If you use <a class="reference internal" href="connection.html#apsw.Connection.__enter__" title="apsw.Connection.__enter__"><code class="xref py py-meth docutils literal notranslate"><span class="pre">with</span> <span class="pre">Connection</span></code></a> then the transaction
will be automatically started, and committed on success or rolled back if
exceptions occur:</p>
<div class="highlight-default notranslate"><div class="highlight"><pre><span></span><span class="c1"># this will be one transaction with automatic commit and rollback</span>
<span class="k">with</span> <span class="n">db</span><span class="p">:</span>
    <span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;INSERT ...&quot;</span><span class="p">)</span>
    <span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;INSERT ...&quot;</span><span class="p">)</span>
    <span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;INSERT ...&quot;</span><span class="p">)</span>
</pre></div>
</div>
<p>There are <a class="reference external" href="https://www.sqlite.org/lang_transaction.html">technical details</a>
at the <a class="reference external" href="https://www.sqlite.org/docs.html">SQLite site</a>.</p>
</section>
<section id="queries">
<h2>Queries<a class="headerlink" href="#queries" title="Link to this heading"></a></h2>
<p>SQLite only calculates each result row as you request it.  For example
if your query returns 10 million rows, SQLite will not calculate all 10
million up front.  Instead the next row will be calculated as you ask
for it.  You can use <a class="reference internal" href="cursor.html#apsw.Cursor.fetchall" title="apsw.Cursor.fetchall"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Cursor.fetchall()</span></code></a> to get all the results.</p>
<p><a class="reference internal" href="cursor.html#apsw.Cursor" title="apsw.Cursor"><code class="xref py py-class docutils literal notranslate"><span class="pre">Cursors</span></code></a> on the same <a class="reference internal" href="connection.html#connections"><span class="std std-ref">Connection</span></a>
are not isolated from each other.  Anything done on one cursor is
immediately visible to all other cursors on the same connection.  This
still applies if you start transactions.  Connections are isolated
from each other.</p>
<p><a class="reference internal" href="connection.html#apsw.Connection.execute" title="apsw.Connection.execute"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.execute()</span></code></a> and <a class="reference internal" href="connection.html#apsw.Connection.executemany" title="apsw.Connection.executemany"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.executemany()</span></code></a>
automatically obtain cursors from  <a class="reference internal" href="connection.html#apsw.Connection.cursor" title="apsw.Connection.cursor"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.cursor()</span></code></a> which
are very cheap.  It is best practise to not re-use them, and instead
get a new one each time.  If you don’t, code refactoring and nested
loops can unintentionally use the same cursor object which will not
crash but will cause hard to diagnose behaviour in your program.</p>
</section>
<section id="bindings">
<h2>Bindings<a class="headerlink" href="#bindings" title="Link to this heading"></a></h2>
<p>When issuing a query, always use bindings.  <a class="reference external" href="https://docs.python.org/3/library/stdtypes.html#printf-style-string-formatting">String interpolation</a>
may seem more convenient but you will encounter difficulties.  You may
feel that you have complete control over all data accessed but if your
code is at all useful then you will find it being used more and more
widely.  The computer will always be better than you at parsing SQL
and the bad guys have years of experience finding and using <a class="reference external" href="https://en.wikipedia.org/wiki/SQL_injection">SQL
injection attacks</a> in
ways you never even thought possible.</p>
<p>The <a class="reference internal" href="example.html#example-why-bindings"><span class="std std-ref">tour</span></a> shows why you use bindings, and
the different ways you can supply them.</p>
</section>
<section id="diagnostics">
<span id="diagnostics-tips"></span><h2>Diagnostics<a class="headerlink" href="#diagnostics" title="Link to this heading"></a></h2>
<p>Both SQLite and APSW provide detailed diagnostic information.  Errors
will be signalled via an <a class="reference internal" href="exceptions.html"><span class="doc">exception</span></a>.</p>
<p>APSW ensures you have <a class="reference internal" href="exceptions.html#augmentedstacktraces"><span class="std std-ref">detailed information</span></a> both in the stack trace as well as what data
APSW/SQLite was operating on.</p>
<p>SQLite has a <a class="reference external" href="https://www.sqlite.org/errlog.html">warning/error logging facility</a>.  Use <a class="reference internal" href="bestpractice.html"><span class="doc">best practice</span></a> to
forward SQLite log messages to Python’s <a class="reference external" href="https://docs.python.org/3/library/logging.html#module-logging" title="(in Python v3.12)"><code class="xref py py-mod docutils literal notranslate"><span class="pre">logging</span></code></a>.</p>
</section>
<section id="managing-and-updating-your-schema">
<h2>Managing and updating your schema<a class="headerlink" href="#managing-and-updating-your-schema" title="Link to this heading"></a></h2>
<p>If your program uses SQLite for <a class="reference external" href="https://sqlite.org/appfileformat.html">data</a> then you’ll need to manage
and update your schema.  The hard way of doing this is to test for the
existence of tables and their columns, and doing that maintenance
programmatically.  The easy way is to use <a class="reference external" href="https://sqlite.org/pragma.html#pragma_user_version">pragma user_version</a> as in this example:</p>
<div class="highlight-default notranslate"><div class="highlight"><pre><span></span><span class="k">def</span> <span class="nf">ensure_schema</span><span class="p">(</span><span class="n">db</span><span class="p">):</span>
  <span class="c1"># a new database starts at user_version 0</span>
  <span class="k">if</span> <span class="n">db</span><span class="o">.</span><span class="n">pragma</span><span class="p">(</span><span class="s2">&quot;user_version&quot;</span><span class="p">)</span> <span class="o">==</span> <span class="mi">0</span><span class="p">:</span>
    <span class="k">with</span> <span class="n">db</span><span class="p">:</span>
      <span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;&quot;&quot;</span>
<span class="s2">        CREATE TABLE foo(x,y,z);</span>
<span class="s2">        CREATE TABLE bar(x,y,z);</span>
<span class="s2">        PRAGMA user_version = 1;&quot;&quot;&quot;</span><span class="p">)</span>

  <span class="k">if</span> <span class="n">db</span><span class="o">.</span><span class="n">pragma</span><span class="p">(</span><span class="s2">&quot;user_version&quot;</span><span class="p">)</span> <span class="o">==</span> <span class="mi">1</span><span class="p">:</span>
    <span class="k">with</span> <span class="n">db</span><span class="p">:</span>
      <span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;&quot;&quot;</span>
<span class="s2">      CREATE TABLE baz(x,y,z);</span>
<span class="s2">      CREATE INDEX ....</span>
<span class="s2">      PRAGMA user_version = 2;&quot;&quot;&quot;</span><span class="p">)</span>

  <span class="k">if</span> <span class="n">db</span><span class="o">.</span><span class="n">pragma</span><span class="p">(</span><span class="s2">&quot;user_version&quot;</span><span class="p">)</span> <span class="o">==</span> <span class="mi">2</span><span class="p">:</span>
    <span class="k">with</span> <span class="n">db</span><span class="p">:</span>
      <span class="n">db</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="s2">&quot;&quot;&quot;</span>
<span class="s2">      ALTER TABLE .....</span>
<span class="s2">      PRAGMA user_version = 3;&quot;&quot;&quot;</span><span class="p">)</span>
</pre></div>
</div>
<p>This approach will automatically upgrade the schema as you expect.
You can also use <a class="reference external" href="https://sqlite.org/pragma.html#pragma_application_id">pragma application_id</a> to mark the
database as made by your application.</p>
</section>
<section id="parsing-sql">
<h2>Parsing SQL<a class="headerlink" href="#parsing-sql" title="Link to this heading"></a></h2>
<p>Sometimes you want to know what a particular SQL statement does.  Use
<a class="reference internal" href="ext.html#apsw.ext.query_info" title="apsw.ext.query_info"><code class="xref py py-func docutils literal notranslate"><span class="pre">apsw.ext.query_info()</span></code></a> which will provide as much detail as you
need.</p>
</section>
<section id="busy-handling">
<span id="busyhandling"></span><h2>Busy handling<a class="headerlink" href="#busy-handling" title="Link to this heading"></a></h2>
<p>SQLite uses locks to coordinate access to the database by multiple
connections (within the same process or in a different process).  The
general goal is to have the locks be as lax as possible (allowing
concurrency) and when using more restrictive locks to keep them for as
short a time as possible.  See the <a class="reference external" href="https://sqlite.org/lockingv3.html">SQLite documentation</a> for more details.</p>
<p>By default you will get an immediate <a class="reference internal" href="exceptions.html#apsw.BusyError" title="apsw.BusyError"><code class="xref py py-exc docutils literal notranslate"><span class="pre">BusyError</span></code></a> if a lock cannot
be acquired. Use <a class="reference internal" href="bestpractice.html"><span class="doc">best practice</span></a> which sets a
short waiting period, as well as enabling <a class="reference external" href="https://www.sqlite.org/wal.html">WAL</a> which reduces contention between
readers and writers.</p>
</section>
<section id="database-schema">
<h2>Database schema<a class="headerlink" href="#database-schema" title="Link to this heading"></a></h2>
<p>When starting a new database, it can be quite difficult to decide what
tables and column to have and how to link them.  The technique used to
design SQL schemas is called <a class="reference external" href="https://en.wikipedia.org/wiki/Database_normalization">normalization</a>.  The page
also shows common pitfalls if you do not normalize your schema.</p>
</section>
<section id="write-ahead-logging">
<span id="wal"></span><h2>Write Ahead Logging<a class="headerlink" href="#write-ahead-logging" title="Link to this heading"></a></h2>
<p>SQLite has <a class="reference external" href="https://sqlite.org/wal.html">write ahead logging</a> which has several benefits, but
also some drawbacks as the page documents.  WAL mode is off by
default. Use <a class="reference internal" href="bestpractice.html"><span class="doc">best practice</span></a> to automatically
enable it for all connections.</p>
<p>Note that if wal mode can’t be set (eg the database is in memory or
temporary) then the attempt to set wal mode will be ignored.  It is
also harmless to call functions like
<a class="reference internal" href="connection.html#apsw.Connection.wal_autocheckpoint" title="apsw.Connection.wal_autocheckpoint"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.wal_autocheckpoint()</span></code></a> on connections that are not in
wal mode.</p>
<p>If you write your own <a class="reference internal" href="vfs.html"><span class="doc">VFS</span></a>, then inheriting from an
existing VFS that supports WAL will make your VFS support the extra
WAL methods too.</p>
</section>
<section id="customizing-connections">
<span id="customizing-connection-cursor"></span><h2>Customizing Connections<a class="headerlink" href="#customizing-connections" title="Link to this heading"></a></h2>
<p><a class="reference internal" href="apsw.html#apsw.connection_hooks" title="apsw.connection_hooks"><code class="xref py py-attr docutils literal notranslate"><span class="pre">apsw.connection_hooks</span></code></a> is a list of callbacks for when
each <a class="reference internal" href="connection.html#apsw.Connection" title="apsw.Connection"><code class="xref py py-class docutils literal notranslate"><span class="pre">Connection</span></code></a> is created.  They are called in turn, with
the new connection as the only parameter.</p>
<p>For example if you wanted to add an <cite>executescript</cite> method to
Connections that is like <a class="reference internal" href="connection.html#apsw.Connection.execute" title="apsw.Connection.execute"><code class="xref py py-meth docutils literal notranslate"><span class="pre">Connection.execute()</span></code></a> but ignores all
returned rows:</p>
<div class="highlight-default notranslate"><div class="highlight"><pre><span></span><span class="k">def</span> <span class="nf">executescript</span><span class="p">(</span><span class="bp">self</span><span class="p">,</span> <span class="n">sql</span><span class="p">,</span> <span class="n">bindings</span><span class="o">=</span><span class="kc">None</span><span class="p">):</span>
  <span class="k">for</span> <span class="n">_</span> <span class="ow">in</span> <span class="bp">self</span><span class="o">.</span><span class="n">execute</span><span class="p">(</span><span class="n">sql</span><span class="p">,</span> <span class="n">bindings</span><span class="p">):</span>
    <span class="k">pass</span>

<span class="k">def</span> <span class="nf">my_hook</span><span class="p">(</span><span class="n">connection</span><span class="p">):</span>
  <span class="n">connection</span><span class="o">.</span><span class="n">executescript</span> <span class="o">=</span> <span class="n">executescript</span>

<span class="n">apsw</span><span class="o">.</span><span class="n">connection_hooks</span><span class="o">.</span><span class="n">append</span><span class="p">(</span><span class="n">my_hook</span><span class="p">)</span>
</pre></div>
</div>
</section>
<section id="customizing-cursors">
<h2>Customizing Cursors<a class="headerlink" href="#customizing-cursors" title="Link to this heading"></a></h2>
<p>You can customize the behaviour of cursors.  An example would be
wanting a <a class="reference internal" href="dbapi.html#rowcount"><span class="std std-ref">rowcount</span></a> or batching returned rows.
(These don’t make any sense with SQLite but the desire may be to make
the code source compatible with other database drivers).</p>
<p>Set <a class="reference internal" href="connection.html#apsw.Connection.cursor_factory" title="apsw.Connection.cursor_factory"><code class="xref py py-attr docutils literal notranslate"><span class="pre">Connection.cursor_factory</span></code></a> to any callable, which will be
called with the connection as the only parameter, and return the
object to use as a cursor.</p>
</section>
</section>


           </div>
          </div>
          <footer><div class="rst-footer-buttons" role="navigation" aria-label="Footer">
        <a href="about.html" class="btn btn-neutral float-left" title="About" accesskey="p" rel="prev"><span class="fa fa-arrow-circle-left" aria-hidden="true"></span> Previous</a>
        <a href="example.html" class="btn btn-neutral float-right" title="Example/Tour" accesskey="n" rel="next">Next <span class="fa fa-arrow-circle-right" aria-hidden="true"></span></a>
    </div>

  <hr/>

  <div role="contentinfo">
    <p>&#169; <a href="copyright.html">Copyright</a> 2004-2024, Roger Binns &lt;rogerb@rogerbinns.com&gt;.
      <span class="lastupdated">Last updated on Jun 16, 2024.
      </span></p>
  </div>

  Built with <a href="https://www.sphinx-doc.org/">Sphinx</a> using a
    <a href="https://github.com/readthedocs/sphinx_rtd_theme">theme</a>
    provided by <a href="https://readthedocs.org">Read the Docs</a>.
   

</footer>
        </div>
      </div>
    </section>
  </div>
  <script>
      jQuery(function () {
          SphinxRtdTheme.Navigation.enable(true);
      });
  </script> 

</body>
</html>