blob: a05f5af5201cdedbf209a015988b0acef0df22e5 [file] [log] [blame]
Gerhard Häringeb2e1922006-04-29 23:12:41 +00001\section{\module{sqlite3} ---
2 DB-API 2.0 interface for SQLite databases}
3
4\declaremodule{builtin}{sqlite3}
Fred Drake6550f032006-05-01 06:25:58 +00005\modulesynopsis{A DB-API 2.0 implementation using SQLite 3.x.}
Gerhard Häring2b161d92006-05-12 23:49:49 +00006\sectionauthor{Gerhard Häring}{gh@ghaering.de}
7\versionadded{2.5}
Gerhard Häringeb2e1922006-04-29 23:12:41 +00008
Andrew M. Kuchlingf36ddda2006-09-08 13:36:57 +00009SQLite is a C library that provides a lightweight disk-based database
10that doesn't require a separate server process and allows accessing
11the database using a nonstandard variant of the SQL query language.
12Some applications can use SQLite for internal data storage. It's also
13possible to prototype an application using SQLite and then port the
14code to a larger database such as PostgreSQL or Oracle.
15
Andrew M. Kuchling12238d72006-06-07 13:55:33 +000016pysqlite was written by Gerhard H\"aring and provides a SQL interface
17compliant with the DB-API 2.0 specification described by
Andrew M. Kuchlingf36ddda2006-09-08 13:36:57 +000018\pep{249}.
Andrew M. Kuchling12238d72006-06-07 13:55:33 +000019
20To use the module, you must first create a \class{Connection} object
21that represents the database. Here the data will be stored in the
22\file{/tmp/example} file:
23
24\begin{verbatim}
25conn = sqlite3.connect('/tmp/example')
26\end{verbatim}
27
28You can also supply the special name \samp{:memory:} to create
29a database in RAM.
30
31Once you have a \class{Connection}, you can create a \class{Cursor}
32object and call its \method{execute()} method to perform SQL commands:
33
34\begin{verbatim}
35c = conn.cursor()
36
37# Create table
38c.execute('''create table stocks
Andrew M. Kuchling9cd00362006-09-08 14:03:19 +000039(date text, trans text, symbol text,
40 qty real, price real)''')
Andrew M. Kuchling12238d72006-06-07 13:55:33 +000041
42# Insert a row of data
43c.execute("""insert into stocks
44 values ('2006-01-05','BUY','RHAT',100,35.14)""")
45\end{verbatim}
46
47Usually your SQL operations will need to use values from Python
48variables. You shouldn't assemble your query using Python's string
49operations because doing so is insecure; it makes your program
50vulnerable to an SQL injection attack.
51
Andrew M. Kuchlinge275d3d2006-06-07 17:04:01 +000052Instead, use the DB-API's parameter substitution. Put \samp{?} as a
Andrew M. Kuchling12238d72006-06-07 13:55:33 +000053placeholder wherever you want to use a value, and then provide a tuple
54of values as the second argument to the cursor's \method{execute()}
Andrew M. Kuchlinge275d3d2006-06-07 17:04:01 +000055method. (Other database modules may use a different placeholder,
56such as \samp{\%s} or \samp{:1}.) For example:
Andrew M. Kuchling12238d72006-06-07 13:55:33 +000057
58\begin{verbatim}
59# Never do this -- insecure!
60symbol = 'IBM'
61c.execute("... where symbol = '%s'" % symbol)
62
63# Do this instead
64t = (symbol,)
65c.execute('select * from stocks where symbol=?', t)
66
67# Larger example
68for t in (('2006-03-28', 'BUY', 'IBM', 1000, 45.00),
69 ('2006-04-05', 'BUY', 'MSOFT', 1000, 72.00),
70 ('2006-04-06', 'SELL', 'IBM', 500, 53.00),
71 ):
72 c.execute('insert into stocks values (?,?,?,?,?)', t)
73\end{verbatim}
74
75To retrieve data after executing a SELECT statement, you can either
76treat the cursor as an iterator, call the cursor's \method{fetchone()}
77method to retrieve a single matching row,
78or call \method{fetchall()} to get a list of the matching rows.
79
80This example uses the iterator form:
81
82\begin{verbatim}
83>>> c = conn.cursor()
84>>> c.execute('select * from stocks order by price')
85>>> for row in c:
86... print row
87...
88(u'2006-01-05', u'BUY', u'RHAT', 100, 35.140000000000001)
89(u'2006-03-28', u'BUY', u'IBM', 1000, 45.0)
90(u'2006-04-06', u'SELL', u'IBM', 500, 53.0)
91(u'2006-04-05', u'BUY', u'MSOFT', 1000, 72.0)
92>>>
93\end{verbatim}
94
95\begin{seealso}
96
97\seeurl{http://www.pysqlite.org}
98{The pysqlite web page.}
99
100\seeurl{http://www.sqlite.org}
101{The SQLite web page; the documentation describes the syntax and the
102available data types for the supported SQL dialect.}
103
104\seepep{249}{Database API Specification 2.0}{PEP written by
105Marc-Andr\'e Lemburg.}
106
107\end{seealso}
108
109
Gerhard Häring2b161d92006-05-12 23:49:49 +0000110\subsection{Module functions and constants\label{sqlite3-Module-Contents}}
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000111
112\begin{datadesc}{PARSE_DECLTYPES}
Gerhard Häring2b161d92006-05-12 23:49:49 +0000113This constant is meant to be used with the \var{detect_types} parameter of the
114\function{connect} function.
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000115
Gerhard Häring2b161d92006-05-12 23:49:49 +0000116Setting it makes the \module{sqlite3} module parse the declared type for each column it
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000117returns. It will parse out the first word of the declared type, i. e. for
118"integer primary key", it will parse out "integer". Then for that column, it
Gerhard Häring2b161d92006-05-12 23:49:49 +0000119will look into the converters dictionary and use the converter function
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000120registered for that type there. Converter names are case-sensitive!
121\end{datadesc}
122
123
124\begin{datadesc}{PARSE_COLNAMES}
Gerhard Häring2b161d92006-05-12 23:49:49 +0000125This constant is meant to be used with the \var{detect_types} parameter of the
126\function{connect} function.
127
128Setting this makes the SQLite interface parse the column name for each column
129it returns. It will look for a string formed [mytype] in there, and then
130decide that 'mytype' is the type of the column. It will try to find an entry of
131'mytype' in the converters dictionary and then use the converter function found
132there to return the value. The column name found in \member{cursor.description} is only
133the first word of the column name, i. e. if you use something like
134\code{'as "x [datetime]"'} in your SQL, then we will parse out everything until the
135first blank for the column name: the column name would simply be "x".
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000136\end{datadesc}
137
Gerhard Häring2b161d92006-05-12 23:49:49 +0000138\begin{funcdesc}{connect}{database\optional{, timeout, isolation_level, detect_types, factory}}
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000139Opens a connection to the SQLite database file \var{database}. You can use
140\code{":memory:"} to open a database connection to a database that resides in
141RAM instead of on disk.
142
143When a database is accessed by multiple connections, and one of the processes
144modifies the database, the SQLite database is locked until that transaction is
145committed. The \var{timeout} parameter specifies how long the connection should
146wait for the lock to go away until raising an exception. The default for the
147timeout parameter is 5.0 (five seconds).
148
Gerhard Häring2b161d92006-05-12 23:49:49 +0000149For the \var{isolation_level} parameter, please see \member{isolation_level}
150\ref{sqlite3-Connection-IsolationLevel} property of \class{Connection} objects.
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000151
152SQLite natively supports only the types TEXT, INTEGER, FLOAT, BLOB and NULL. If
153you want to use other types, like you have to add support for them yourself.
Gerhard Häring2b161d92006-05-12 23:49:49 +0000154The \var{detect_types} parameter and the using custom \strong{converters} registered with
155the module-level \function{register_converter} function allow you to easily do that.
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000156
157\var{detect_types} defaults to 0 (i. e. off, no type detection), you can set it
Gerhard Häring2b161d92006-05-12 23:49:49 +0000158to any combination of \constant{PARSE_DECLTYPES} and \constant{PARSE_COLNAMES} to turn type
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000159detection on.
160
Gerhard Häring2b161d92006-05-12 23:49:49 +0000161By default, the \module{sqlite3} module uses its \class{Connection} class for the
162connect call. You can, however, subclass the \class{Connection} class and make
163\function{connect} use your class instead by providing your class for the
164\var{factory} parameter.
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000165
Gerhard Häring2b161d92006-05-12 23:49:49 +0000166Consult the section \ref{sqlite3-Types} of this manual for details.
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000167
Gerhard Häring2b161d92006-05-12 23:49:49 +0000168The \module{sqlite3} module internally uses a statement cache to avoid SQL parsing
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000169overhead. If you want to explicitly set the number of statements that are
170cached for the connection, you can set the \var{cached_statements} parameter.
171The currently implemented default is to cache 100 statements.
172\end{funcdesc}
173
174\begin{funcdesc}{register_converter}{typename, callable}
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000175Registers a callable to convert a bytestring from the database into a custom
176Python type. The callable will be invoked for all database values that are of
Gerhard Häring2b161d92006-05-12 23:49:49 +0000177the type \var{typename}. Confer the parameter \var{detect_types} of the
178\function{connect} function for how the type detection works. Note that the case of
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000179\var{typename} and the name of the type in your query must match!
180\end{funcdesc}
181
182\begin{funcdesc}{register_adapter}{type, callable}
183Registers a callable to convert the custom Python type \var{type} into one of
184SQLite's supported types. The callable \var{callable} accepts as single
185parameter the Python value, and must return a value of the following types:
186int, long, float, str (UTF-8 encoded), unicode or buffer.
187\end{funcdesc}
188
Gerhard Häring2b161d92006-05-12 23:49:49 +0000189\begin{funcdesc}{complete_statement}{sql}
190Returns \constant{True} if the string \var{sql} one or more complete SQL
191statements terminated by semicolons. It does not verify if the SQL is
192syntactically correct, only if there are no unclosed string literals and if the
193statement is terminated by a semicolon.
194
195This can be used to build a shell for SQLite, like in the following example:
196
197 \verbatiminput{sqlite3/complete_statement.py}
198\end{funcdesc}
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000199
Gerhard Häring5d7c2902006-06-13 22:53:48 +0000200\begin{funcdesc}{}enable_callback_tracebacks{flag}
201By default you will not get any tracebacks in user-defined functions,
202aggregates, converters, authorizer callbacks etc. If you want to debug them,
203you can call this function with \var{flag} as True. Afterwards, you will get
204tracebacks from callbacks on \code{sys.stderr}. Use \constant{False} to disable
205the feature again.
206\end{funcdesc}
207
Fred Drake6550f032006-05-01 06:25:58 +0000208\subsection{Connection Objects \label{sqlite3-Connection-Objects}}
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000209
210A \class{Connection} instance has the following attributes and methods:
211
Gerhard Häring2b161d92006-05-12 23:49:49 +0000212\label{sqlite3-Connection-IsolationLevel}
Fred Drake6550f032006-05-01 06:25:58 +0000213\begin{memberdesc}{isolation_level}
Gerhard Häring2b161d92006-05-12 23:49:49 +0000214 Get or set the current isolation level. None for autocommit mode or one of
215 "DEFERRED", "IMMEDIATE" or "EXLUSIVE". See Controlling Transactions
216 \ref{sqlite3-Controlling-Transactions} for a more detailed explanation.
Fred Drake6550f032006-05-01 06:25:58 +0000217\end{memberdesc}
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000218
219\begin{methoddesc}{cursor}{\optional{cursorClass}}
Fred Drake6550f032006-05-01 06:25:58 +0000220 The cursor method accepts a single optional parameter \var{cursorClass}.
221 This is a custom cursor class which must extend \class{sqlite3.Cursor}.
Gerhard Häringeb2e1922006-04-29 23:12:41 +0000222\end{methoddesc}
223
Gerhard Häring82560eb2006-05-01 15:14:48 +0000224\begin{methoddesc}{execute}{sql, \optional{parameters}}
225This is a nonstandard shortcut that creates an intermediate cursor object by
Gerhard Häring2b161d92006-05-12 23:49:49 +0000226calling the cursor method, then calls the cursor's \method{execute} method with the
Gerhard Häring82560eb2006-05-01 15:14:48 +0000227parameters given.
228\end{methoddesc}
229
230\begin{methoddesc}{executemany}{sql, \optional{parameters}}
231This is a nonstandard shortcut that creates an intermediate cursor object by
Gerhard Häring2b161d92006-05-12 23:49:49 +0000232calling the cursor method, then calls the cursor's \method{executemany} method with the
Gerhard Häring82560eb2006-05-01 15:14:48 +0000233parameters given.
234\end{methoddesc}
235
236\begin{methoddesc}{executescript}{sql_script}
237This is a nonstandard shortcut that creates an intermediate cursor object by
Gerhard Häring2b161d92006-05-12 23:49:49 +0000238calling the cursor method, then calls the cursor's \method{executescript} method with the
Gerhard Häring82560eb2006-05-01 15:14:48 +0000239parameters given.
240\end{methoddesc}
241
Gerhard Häring2b161d92006-05-12 23:49:49 +0000242\begin{methoddesc}{create_function}{name, num_params, func}
243
244Creates a user-defined function that you can later use from within SQL
245statements under the function name \var{name}. \var{num_params} is the number
246of parameters the function accepts, and \var{func} is a Python callable that is
247called as SQL function.
248
249The function can return any of the types supported by SQLite: unicode, str,
Gerhard Häring5d7c2902006-06-13 22:53:48 +0000250int, long, float, buffer and None.
Gerhard Häring2b161d92006-05-12 23:49:49 +0000251
252Example:
253
254 \verbatiminput{sqlite3/md5func.py}
255\end{methoddesc}
256
257\begin{methoddesc}{create_aggregate}{name, num_params, aggregate_class}
258
259Creates a user-defined aggregate function.
260
261The aggregate class must implement a \code{step} method, which accepts the
262number of parameters \var{num_params}, and a \code{finalize} method which
263will return the final result of the aggregate.
264
265The \code{finalize} method can return any of the types supported by SQLite:
Gerhard Häring5d7c2902006-06-13 22:53:48 +0000266unicode, str, int, long, float, buffer and None.
Gerhard Häring2b161d92006-05-12 23:49:49 +0000267
268Example:
269
270 \verbatiminput{sqlite3/mysumaggr.py}
271\end{methoddesc}
272
273\begin{methoddesc}{create_collation}{name, callable}
274
275Creates a collation with the specified \var{name} and \var{callable}. The
276callable will be passed two string arguments. It should return -1 if the first
277is ordered lower than the second, 0 if they are ordered equal and 1 and if the
278first is ordered higher than the second. Note that this controls sorting
279(ORDER BY in SQL) so your comparisons don't affect other SQL operations.
280
281Note that the callable will get its parameters as Python bytestrings, which
282will normally be encoded in UTF-8.
283
284The following example shows a custom collation that sorts "the wrong way":
285
286 \verbatiminput{sqlite3/collation_reverse.py}
287
288To remove a collation, call \code{create_collation} with None as callable:
289
290\begin{verbatim}
291 con.create_collation("reverse", None)
292\end{verbatim}
293\end{methoddesc}
294
Gerhard Häring5d7c2902006-06-13 22:53:48 +0000295\begin{methoddesc}{interrupt}{}
296
297You can call this method from a different thread to abort any queries that
298might be executing on the connection. The query will then abort and the caller
299will get an exception.
300\end{methoddesc}
301
302\begin{methoddesc}{set_authorizer}{authorizer_callback}
303
304This routine registers a callback. The callback is invoked for each attempt to
305access a column of a table in the database. The callback should return
306\constant{SQLITE_OK} if access is allowed, \constant{SQLITE_DENY} if the entire
307SQL statement should be aborted with an error and \constant{SQLITE_IGNORE} if
308the column should be treated as a NULL value. These constants are available in
309the \module{sqlite3} module.
310
311The first argument to the callback signifies what kind of operation is to be
312authorized. The second and third argument will be arguments or \constant{None}
313depending on the first argument. The 4th argument is the name of the database
314("main", "temp", etc.) if applicable. The 5th argument is the name of the
315inner-most trigger or view that is responsible for the access attempt or
316\constant{None} if this access attempt is directly from input SQL code.
317
318Please consult the SQLite documentation about the possible values for the first
319argument and the meaning of the second and third argument depending on the
320first one. All necessary constants are available in the \module{sqlite3}
321module.
322\end{methoddesc}
Gerhard Häring2b161d92006-05-12 23:49:49 +0000323
Gerhard Häring82560eb2006-05-01 15:14:48 +0000324\begin{memberdesc}{row_factory}
325 You can change this attribute to a callable that accepts the cursor and
326 the original row as tuple and will return the real result row. This
327 way, you can implement more advanced ways of returning results, like
328 ones that can also access columns by name.
329
330 Example:
331
332 \verbatiminput{sqlite3/row_factory.py}
333
334 If the standard tuple types don't suffice for you, and you want name-based
335 access to columns, you should consider setting \member{row_factory} to the
Gerhard Häring2b161d92006-05-12 23:49:49 +0000336 highly-optimized sqlite3.Row type. It provides both
Gerhard Häring82560eb2006-05-01 15:14:48 +0000337 index-based and case-insensitive name-based access to columns with almost
338 no memory overhead. Much better than your own custom dictionary-based
339 approach or even a db_row based solution.
340\end{memberdesc}
341
342\begin{memberdesc}{text_factory}
Gerhard Häring2b161d92006-05-12 23:49:49 +0000343 Using this attribute you can control what objects are returned for the
344 TEXT data type. By default, this attribute is set to \class{unicode} and
345 the \module{sqlite3} module will return Unicode objects for TEXT. If you want to return
346 bytestrings instead, you can set it to \class{str}.
Gerhard Häring82560eb2006-05-01 15:14:48 +0000347
348 For efficiency reasons, there's also a way to return Unicode objects only
349 for non-ASCII data, and bytestrings otherwise. To activate it, set this
Gerhard Häring2b161d92006-05-12 23:49:49 +0000350 attribute to \constant{sqlite3.OptimizedUnicode}.
Gerhard Häring82560eb2006-05-01 15:14:48 +0000351
352 You can also set it to any other callable that accepts a single bytestring
353 parameter and returns the result object.
354
355 See the following example code for illustration:
356
357 \verbatiminput{sqlite3/text_factory.py}
358\end{memberdesc}
359
360\begin{memberdesc}{total_changes}
361 Returns the total number of database rows that have be modified, inserted,
362 or deleted since the database connection was opened.
363\end{memberdesc}
364
365
366
367
368
Gerhard Häring2b161d92006-05-12 23:49:49 +0000369\subsection{Cursor Objects \label{sqlite3-Cursor-Objects}}
Gerhard Häring82560eb2006-05-01 15:14:48 +0000370
371A \class{Cursor} instance has the following attributes and methods:
372
373\begin{methoddesc}{execute}{sql, \optional{parameters}}
374
375Executes a SQL statement. The SQL statement may be parametrized (i. e.
Gerhard Häring2b161d92006-05-12 23:49:49 +0000376placeholders instead of SQL literals). The \module{sqlite3} module supports two kinds of
Gerhard Häring82560eb2006-05-01 15:14:48 +0000377placeholders: question marks (qmark style) and named placeholders (named
378style).
379
380This example shows how to use parameters with qmark style:
381
382 \verbatiminput{sqlite3/execute_1.py}
383
384This example shows how to use the named style:
385
386 \verbatiminput{sqlite3/execute_2.py}
387
388 \method{execute} will only execute a single SQL statement. If you try to
389 execute more than one statement with it, it will raise a Warning. Use
390 \method{executescript} if want to execute multiple SQL statements with one
391 call.
392\end{methoddesc}
393
394
395\begin{methoddesc}{executemany}{sql, seq_of_parameters}
396Executes a SQL command against all parameter sequences or mappings found in the
397sequence \var{sql}. The \module{sqlite3} module also allows
398to use an iterator yielding parameters instead of a sequence.
399
400\verbatiminput{sqlite3/executemany_1.py}
401
402Here's a shorter example using a generator:
403
404\verbatiminput{sqlite3/executemany_2.py}
405\end{methoddesc}
406
407\begin{methoddesc}{executescript}{sql_script}
408
409This is a nonstandard convenience method for executing multiple SQL statements
410at once. It issues a COMMIT statement before, then executes the SQL script it
411gets as a parameter.
412
413\var{sql_script} can be a bytestring or a Unicode string.
414
415Example:
416
417\verbatiminput{sqlite3/executescript.py}
418\end{methoddesc}
419
420\begin{memberdesc}{rowcount}
Gerhard Häring2b161d92006-05-12 23:49:49 +0000421 Although the \class{Cursor} class of the \module{sqlite3} module implements this
Gerhard Häring82560eb2006-05-01 15:14:48 +0000422 attribute, the database engine's own support for the determination of "rows
423 affected"/"rows selected" is quirky.
424
425 For \code{SELECT} statements, \member{rowcount} is always None because we cannot
426 determine the number of rows a query produced until all rows were fetched.
427
428 For \code{DELETE} statements, SQLite reports \member{rowcount} as 0 if you make a
429 \code{DELETE FROM table} without any condition.
430
Gerhard Häring2b161d92006-05-12 23:49:49 +0000431 For \method{executemany} statements, the number of modifications are summed
432 up into \member{rowcount}.
Gerhard Häring82560eb2006-05-01 15:14:48 +0000433
434 As required by the Python DB API Spec, the \member{rowcount} attribute "is -1
435 in case no executeXX() has been performed on the cursor or the rowcount
436 of the last operation is not determinable by the interface".
437\end{memberdesc}
438
Gerhard Häring2b161d92006-05-12 23:49:49 +0000439\subsection{SQLite and Python types\label{sqlite3-Types}}
440
441\subsubsection{Introduction}
442
443SQLite natively supports the following types: NULL, INTEGER, REAL, TEXT, BLOB.
444
445The following Python types can thus be sent to SQLite without any problem:
446
447\begin{tableii} {c|l}{code}{Python type}{SQLite type}
448\lineii{None}{NULL}
449\lineii{int}{INTEGER}
450\lineii{long}{INTEGER}
451\lineii{float}{REAL}
452\lineii{str (UTF8-encoded)}{TEXT}
453\lineii{unicode}{TEXT}
454\lineii{buffer}{BLOB}
455\end{tableii}
456
457This is how SQLite types are converted to Python types by default:
458
459\begin{tableii} {c|l}{code}{SQLite type}{Python type}
460\lineii{NULL}{None}
461\lineii{INTEGER}{int or long, depending on size}
462\lineii{REAL}{float}
463\lineii{TEXT}{depends on text_factory, unicode by default}
464\lineii{BLOB}{buffer}
465\end{tableii}
466
467The type system of the \module{sqlite3} module is extensible in both ways: you can store
468additional Python types in a SQLite database via object adaptation, and you can
469let the \module{sqlite3} module convert SQLite types to different Python types via
470converters.
471
472\subsubsection{Using adapters to store additional Python types in SQLite databases}
473
474Like described before, SQLite supports only a limited set of types natively. To
475use other Python types with SQLite, you must \strong{adapt} them to one of the sqlite3
476module's supported types for SQLite. So, one of NoneType, int, long, float,
477str, unicode, buffer.
478
479The \module{sqlite3} module uses the Python object adaptation, like described in PEP 246
480for this. The protocol to use is \class{PrepareProtocol}.
481
482There are two ways to enable the \module{sqlite3} module to adapt a custom Python type
483to one of the supported ones.
484
485\paragraph{Letting your object adapt itself}
486
487This is a good approach if you write the class yourself. Let's suppose you have
488a class like this:
489
490\begin{verbatim}
491class Point(object):
492 def __init__(self, x, y):
493 self.x, self.y = x, y
494\end{verbatim}
495
496Now you want to store the point in a single SQLite column. You'll have to
497choose one of the supported types first that you use to represent the point in.
498Let's just use str and separate the coordinates using a semicolon. Then you
499need to give your class a method \code{__conform__(self, protocol)} which must
500return the converted value. The parameter \var{protocol} will be
501\class{PrepareProtocol}.
502
503\verbatiminput{sqlite3/adapter_point_1.py}
504
505\paragraph{Registering an adapter callable}
506
507The other possibility is to create a function that converts the type to the
508string representation and register the function with \method{register_adapter}.
509
510 \verbatiminput{sqlite3/adapter_point_2.py}
511
512\begin{notice}
513The type/class to adapt must be a new-style class, i. e. it must have
514\class{object} as one of its bases.
515\end{notice}
516
Fred Drakee0d4aec2006-07-30 03:03:43 +0000517The \module{sqlite3} module has two default adapters for Python's built-in
518\class{datetime.date} and \class{datetime.datetime} types. Now let's suppose
519we want to store \class{datetime.datetime} objects not in ISO representation,
520but as a \UNIX{} timestamp.
Gerhard Häring2b161d92006-05-12 23:49:49 +0000521
522 \verbatiminput{sqlite3/adapter_datetime.py}
523
524\subsubsection{Converting SQLite values to custom Python types}
525
526Now that's all nice and dandy that you can send custom Python types to SQLite.
527But to make it really useful we need to make the Python to SQLite to Python
528roundtrip work.
529
530Enter converters.
531
532Let's go back to the Point class. We stored the x and y coordinates separated
533via semicolons as strings in SQLite.
534
535Let's first define a converter function that accepts the string as a parameter and constructs a Point object from it.
536
537\begin{notice}
538Converter functions \strong{always} get called with a string, no matter
539under which data type you sent the value to SQLite.
540\end{notice}
541
542\begin{notice}
543Converter names are looked up in a case-sensitive manner.
544\end{notice}
545
546
547\begin{verbatim}
548 def convert_point(s):
549 x, y = map(float, s.split(";"))
550 return Point(x, y)
551\end{verbatim}
552
553Now you need to make the \module{sqlite3} module know that what you select from the
554database is actually a point. There are two ways of doing this:
555
556\begin{itemize}
557 \item Implicitly via the declared type
558 \item Explicitly via the column name
559\end{itemize}
560
561Both ways are described at \ref{sqlite3-Module-Contents} in the text explaining
562the constants \constant{PARSE_DECLTYPES} and \constant{PARSE_COlNAMES}.
563
564
565The following example illustrates both ways.
566
567 \verbatiminput{sqlite3/converter_point.py}
568
569\subsubsection{Default adapters and converters}
570
571There are default adapters for the date and datetime types in the datetime
572module. They will be sent as ISO dates/ISO timestamps to SQLite.
573
574The default converters are registered under the name "date" for datetime.date
575and under the name "timestamp" for datetime.datetime.
576
577This way, you can use date/timestamps from Python without any additional
578fiddling in most cases. The format of the adapters is also compatible with the
579experimental SQLite date/time functions.
580
581The following example demonstrates this.
582
583 \verbatiminput{sqlite3/pysqlite_datetime.py}
584
585\subsection{Controlling Transactions \label{sqlite3-Controlling-Transactions}}
586
587By default, the \module{sqlite3} module opens transactions implicitly before a DML
588statement (INSERT/UPDATE/DELETE/REPLACE), and commits transactions implicitly
589before a non-DML, non-DQL statement (i. e. anything other than
590SELECT/INSERT/UPDATE/DELETE/REPLACE).
591
592So if you are within a transaction, and issue a command like \code{CREATE TABLE
593...}, \code{VACUUM}, \code{PRAGMA}, the \module{sqlite3} module will commit implicitly
594before executing that command. There are two reasons for doing that. The first
595is that some of these commands don't work within transactions. The other reason
596is that pysqlite needs to keep track of the transaction state (if a transaction
597is active or not).
598
599You can control which kind of "BEGIN" statements pysqlite implicitly executes
600(or none at all) via the \var{isolation_level} parameter to the
601\function{connect} call, or via the \member{isolation_level} property of
602connections.
603
604If you want \strong{autocommit mode}, then set \member{isolation_level} to None.
605
Andrew M. Kuchling06c5c8a2006-06-08 11:56:44 +0000606Otherwise leave it at its default, which will result in a plain "BEGIN"
Gerhard Häring2b161d92006-05-12 23:49:49 +0000607statement, or set it to one of SQLite's supported isolation levels: DEFERRED,
608IMMEDIATE or EXCLUSIVE.
609
610As the \module{sqlite3} module needs to keep track of the transaction state, you should
611not use \code{OR ROLLBACK} or \code{ON CONFLICT ROLLBACK} in your SQL. Instead,
612catch the \exception{IntegrityError} and call the \method{rollback} method of
613the connection yourself.
614
615\subsection{Using pysqlite efficiently}
616
617\subsubsection{Using shortcut methods}
618
619Using the nonstandard \method{execute}, \method{executemany} and
620\method{executescript} methods of the \class{Connection} object, your code can
621be written more concisely, because you don't have to create the - often
622superfluous \class{Cursor} objects explicitly. Instead, the \class{Cursor}
623objects are created implicitly and these shortcut methods return the cursor
624objects. This way, you can for example execute a SELECT statement and iterate
625over it directly using only a single call on the \class{Connection} object.
626
627 \verbatiminput{sqlite3/shortcut_methods.py}
628
629\subsubsection{Accessing columns by name instead of by index}
630
631One cool feature of the \module{sqlite3} module is the builtin \class{sqlite3.Row} class
632designed to be used as a row factory.
633
634Rows wrapped with this class can be accessed both by index (like tuples) and
635case-insensitively by name:
636
637 \verbatiminput{sqlite3/rowclass.py}
638
639