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