blob: d87e064728d1fb6943e99d33f9c510eea7e7f845 [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
Thomas Wouters0e3f5912006-08-11 14:57:12 +0000198\begin{funcdesc}{}enable_callback_tracebacks{flag}
199By default you will not get any tracebacks in user-defined functions,
200aggregates, converters, authorizer callbacks etc. If you want to debug them,
201you can call this function with \var{flag} as True. Afterwards, you will get
202tracebacks from callbacks on \code{sys.stderr}. Use \constant{False} to disable
203the feature again.
204\end{funcdesc}
205
Thomas Wouters477c8d52006-05-27 19:21:47 +0000206\subsection{Connection Objects \label{sqlite3-Connection-Objects}}
207
208A \class{Connection} instance has the following attributes and methods:
209
210\label{sqlite3-Connection-IsolationLevel}
211\begin{memberdesc}{isolation_level}
212 Get or set the current isolation level. None for autocommit mode or one of
213 "DEFERRED", "IMMEDIATE" or "EXLUSIVE". See Controlling Transactions
214 \ref{sqlite3-Controlling-Transactions} for a more detailed explanation.
215\end{memberdesc}
216
217\begin{methoddesc}{cursor}{\optional{cursorClass}}
218 The cursor method accepts a single optional parameter \var{cursorClass}.
219 This is a custom cursor class which must extend \class{sqlite3.Cursor}.
220\end{methoddesc}
221
222\begin{methoddesc}{execute}{sql, \optional{parameters}}
223This is a nonstandard shortcut that creates an intermediate cursor object by
224calling the cursor method, then calls the cursor's \method{execute} method with the
225parameters given.
226\end{methoddesc}
227
228\begin{methoddesc}{executemany}{sql, \optional{parameters}}
229This is a nonstandard shortcut that creates an intermediate cursor object by
230calling the cursor method, then calls the cursor's \method{executemany} method with the
231parameters given.
232\end{methoddesc}
233
234\begin{methoddesc}{executescript}{sql_script}
235This is a nonstandard shortcut that creates an intermediate cursor object by
236calling the cursor method, then calls the cursor's \method{executescript} method with the
237parameters given.
238\end{methoddesc}
239
240\begin{methoddesc}{create_function}{name, num_params, func}
241
242Creates a user-defined function that you can later use from within SQL
243statements under the function name \var{name}. \var{num_params} is the number
244of parameters the function accepts, and \var{func} is a Python callable that is
245called as SQL function.
246
247The function can return any of the types supported by SQLite: unicode, str,
Thomas Wouters0e3f5912006-08-11 14:57:12 +0000248int, long, float, buffer and None.
Thomas Wouters477c8d52006-05-27 19:21:47 +0000249
250Example:
251
252 \verbatiminput{sqlite3/md5func.py}
253\end{methoddesc}
254
255\begin{methoddesc}{create_aggregate}{name, num_params, aggregate_class}
256
257Creates a user-defined aggregate function.
258
259The aggregate class must implement a \code{step} method, which accepts the
260number of parameters \var{num_params}, and a \code{finalize} method which
261will return the final result of the aggregate.
262
263The \code{finalize} method can return any of the types supported by SQLite:
Thomas Wouters0e3f5912006-08-11 14:57:12 +0000264unicode, str, int, long, float, buffer and None.
Thomas Wouters477c8d52006-05-27 19:21:47 +0000265
266Example:
267
268 \verbatiminput{sqlite3/mysumaggr.py}
269\end{methoddesc}
270
271\begin{methoddesc}{create_collation}{name, callable}
272
273Creates a collation with the specified \var{name} and \var{callable}. The
274callable will be passed two string arguments. It should return -1 if the first
275is ordered lower than the second, 0 if they are ordered equal and 1 and if the
276first is ordered higher than the second. Note that this controls sorting
277(ORDER BY in SQL) so your comparisons don't affect other SQL operations.
278
279Note that the callable will get its parameters as Python bytestrings, which
280will normally be encoded in UTF-8.
281
282The following example shows a custom collation that sorts "the wrong way":
283
284 \verbatiminput{sqlite3/collation_reverse.py}
285
286To remove a collation, call \code{create_collation} with None as callable:
287
288\begin{verbatim}
289 con.create_collation("reverse", None)
290\end{verbatim}
291\end{methoddesc}
292
Thomas Wouters0e3f5912006-08-11 14:57:12 +0000293\begin{methoddesc}{interrupt}{}
294
295You can call this method from a different thread to abort any queries that
296might be executing on the connection. The query will then abort and the caller
297will get an exception.
298\end{methoddesc}
299
300\begin{methoddesc}{set_authorizer}{authorizer_callback}
301
302This routine registers a callback. The callback is invoked for each attempt to
303access a column of a table in the database. The callback should return
304\constant{SQLITE_OK} if access is allowed, \constant{SQLITE_DENY} if the entire
305SQL statement should be aborted with an error and \constant{SQLITE_IGNORE} if
306the column should be treated as a NULL value. These constants are available in
307the \module{sqlite3} module.
308
309The first argument to the callback signifies what kind of operation is to be
310authorized. The second and third argument will be arguments or \constant{None}
311depending on the first argument. The 4th argument is the name of the database
312("main", "temp", etc.) if applicable. The 5th argument is the name of the
313inner-most trigger or view that is responsible for the access attempt or
314\constant{None} if this access attempt is directly from input SQL code.
315
316Please consult the SQLite documentation about the possible values for the first
317argument and the meaning of the second and third argument depending on the
318first one. All necessary constants are available in the \module{sqlite3}
319module.
320\end{methoddesc}
Thomas Wouters477c8d52006-05-27 19:21:47 +0000321
322\begin{memberdesc}{row_factory}
323 You can change this attribute to a callable that accepts the cursor and
324 the original row as tuple and will return the real result row. This
325 way, you can implement more advanced ways of returning results, like
326 ones that can also access columns by name.
327
328 Example:
329
330 \verbatiminput{sqlite3/row_factory.py}
331
332 If the standard tuple types don't suffice for you, and you want name-based
333 access to columns, you should consider setting \member{row_factory} to the
334 highly-optimized sqlite3.Row type. It provides both
335 index-based and case-insensitive name-based access to columns with almost
336 no memory overhead. Much better than your own custom dictionary-based
337 approach or even a db_row based solution.
338\end{memberdesc}
339
340\begin{memberdesc}{text_factory}
341 Using this attribute you can control what objects are returned for the
342 TEXT data type. By default, this attribute is set to \class{unicode} and
343 the \module{sqlite3} module will return Unicode objects for TEXT. If you want to return
344 bytestrings instead, you can set it to \class{str}.
345
346 For efficiency reasons, there's also a way to return Unicode objects only
347 for non-ASCII data, and bytestrings otherwise. To activate it, set this
348 attribute to \constant{sqlite3.OptimizedUnicode}.
349
350 You can also set it to any other callable that accepts a single bytestring
351 parameter and returns the result object.
352
353 See the following example code for illustration:
354
355 \verbatiminput{sqlite3/text_factory.py}
356\end{memberdesc}
357
358\begin{memberdesc}{total_changes}
359 Returns the total number of database rows that have be modified, inserted,
360 or deleted since the database connection was opened.
361\end{memberdesc}
362
363
364
365
366
367\subsection{Cursor Objects \label{sqlite3-Cursor-Objects}}
368
369A \class{Cursor} instance has the following attributes and methods:
370
371\begin{methoddesc}{execute}{sql, \optional{parameters}}
372
373Executes a SQL statement. The SQL statement may be parametrized (i. e.
374placeholders instead of SQL literals). The \module{sqlite3} module supports two kinds of
375placeholders: question marks (qmark style) and named placeholders (named
376style).
377
378This example shows how to use parameters with qmark style:
379
380 \verbatiminput{sqlite3/execute_1.py}
381
382This example shows how to use the named style:
383
384 \verbatiminput{sqlite3/execute_2.py}
385
386 \method{execute} will only execute a single SQL statement. If you try to
387 execute more than one statement with it, it will raise a Warning. Use
388 \method{executescript} if want to execute multiple SQL statements with one
389 call.
390\end{methoddesc}
391
392
393\begin{methoddesc}{executemany}{sql, seq_of_parameters}
394Executes a SQL command against all parameter sequences or mappings found in the
395sequence \var{sql}. The \module{sqlite3} module also allows
396to use an iterator yielding parameters instead of a sequence.
397
398\verbatiminput{sqlite3/executemany_1.py}
399
400Here's a shorter example using a generator:
401
402\verbatiminput{sqlite3/executemany_2.py}
403\end{methoddesc}
404
405\begin{methoddesc}{executescript}{sql_script}
406
407This is a nonstandard convenience method for executing multiple SQL statements
408at once. It issues a COMMIT statement before, then executes the SQL script it
409gets as a parameter.
410
411\var{sql_script} can be a bytestring or a Unicode string.
412
413Example:
414
415\verbatiminput{sqlite3/executescript.py}
416\end{methoddesc}
417
418\begin{memberdesc}{rowcount}
419 Although the \class{Cursor} class of the \module{sqlite3} module implements this
420 attribute, the database engine's own support for the determination of "rows
421 affected"/"rows selected" is quirky.
422
423 For \code{SELECT} statements, \member{rowcount} is always None because we cannot
424 determine the number of rows a query produced until all rows were fetched.
425
426 For \code{DELETE} statements, SQLite reports \member{rowcount} as 0 if you make a
427 \code{DELETE FROM table} without any condition.
428
429 For \method{executemany} statements, the number of modifications are summed
430 up into \member{rowcount}.
431
432 As required by the Python DB API Spec, the \member{rowcount} attribute "is -1
433 in case no executeXX() has been performed on the cursor or the rowcount
434 of the last operation is not determinable by the interface".
435\end{memberdesc}
436
437\subsection{SQLite and Python types\label{sqlite3-Types}}
438
439\subsubsection{Introduction}
440
441SQLite natively supports the following types: NULL, INTEGER, REAL, TEXT, BLOB.
442
443The following Python types can thus be sent to SQLite without any problem:
444
445\begin{tableii} {c|l}{code}{Python type}{SQLite type}
446\lineii{None}{NULL}
447\lineii{int}{INTEGER}
448\lineii{long}{INTEGER}
449\lineii{float}{REAL}
450\lineii{str (UTF8-encoded)}{TEXT}
451\lineii{unicode}{TEXT}
452\lineii{buffer}{BLOB}
453\end{tableii}
454
455This is how SQLite types are converted to Python types by default:
456
457\begin{tableii} {c|l}{code}{SQLite type}{Python type}
458\lineii{NULL}{None}
459\lineii{INTEGER}{int or long, depending on size}
460\lineii{REAL}{float}
461\lineii{TEXT}{depends on text_factory, unicode by default}
462\lineii{BLOB}{buffer}
463\end{tableii}
464
465The type system of the \module{sqlite3} module is extensible in both ways: you can store
466additional Python types in a SQLite database via object adaptation, and you can
467let the \module{sqlite3} module convert SQLite types to different Python types via
468converters.
469
470\subsubsection{Using adapters to store additional Python types in SQLite databases}
471
472Like described before, SQLite supports only a limited set of types natively. To
473use other Python types with SQLite, you must \strong{adapt} them to one of the sqlite3
474module's supported types for SQLite. So, one of NoneType, int, long, float,
475str, unicode, buffer.
476
477The \module{sqlite3} module uses the Python object adaptation, like described in PEP 246
478for this. The protocol to use is \class{PrepareProtocol}.
479
480There are two ways to enable the \module{sqlite3} module to adapt a custom Python type
481to one of the supported ones.
482
483\paragraph{Letting your object adapt itself}
484
485This is a good approach if you write the class yourself. Let's suppose you have
486a class like this:
487
488\begin{verbatim}
489class Point(object):
490 def __init__(self, x, y):
491 self.x, self.y = x, y
492\end{verbatim}
493
494Now you want to store the point in a single SQLite column. You'll have to
495choose one of the supported types first that you use to represent the point in.
496Let's just use str and separate the coordinates using a semicolon. Then you
497need to give your class a method \code{__conform__(self, protocol)} which must
498return the converted value. The parameter \var{protocol} will be
499\class{PrepareProtocol}.
500
501\verbatiminput{sqlite3/adapter_point_1.py}
502
503\paragraph{Registering an adapter callable}
504
505The other possibility is to create a function that converts the type to the
506string representation and register the function with \method{register_adapter}.
507
508 \verbatiminput{sqlite3/adapter_point_2.py}
509
510\begin{notice}
511The type/class to adapt must be a new-style class, i. e. it must have
512\class{object} as one of its bases.
513\end{notice}
514
Thomas Wouters0e3f5912006-08-11 14:57:12 +0000515The \module{sqlite3} module has two default adapters for Python's built-in
516\class{datetime.date} and \class{datetime.datetime} types. Now let's suppose
517we want to store \class{datetime.datetime} objects not in ISO representation,
518but as a \UNIX{} timestamp.
Thomas Wouters477c8d52006-05-27 19:21:47 +0000519
520 \verbatiminput{sqlite3/adapter_datetime.py}
521
522\subsubsection{Converting SQLite values to custom Python types}
523
524Now that's all nice and dandy that you can send custom Python types to SQLite.
525But to make it really useful we need to make the Python to SQLite to Python
526roundtrip work.
527
528Enter converters.
529
530Let's go back to the Point class. We stored the x and y coordinates separated
531via semicolons as strings in SQLite.
532
533Let's first define a converter function that accepts the string as a parameter and constructs a Point object from it.
534
535\begin{notice}
536Converter functions \strong{always} get called with a string, no matter
537under which data type you sent the value to SQLite.
538\end{notice}
539
540\begin{notice}
541Converter names are looked up in a case-sensitive manner.
542\end{notice}
543
544
545\begin{verbatim}
546 def convert_point(s):
547 x, y = map(float, s.split(";"))
548 return Point(x, y)
549\end{verbatim}
550
551Now you need to make the \module{sqlite3} module know that what you select from the
552database is actually a point. There are two ways of doing this:
553
554\begin{itemize}
555 \item Implicitly via the declared type
556 \item Explicitly via the column name
557\end{itemize}
558
559Both ways are described at \ref{sqlite3-Module-Contents} in the text explaining
560the constants \constant{PARSE_DECLTYPES} and \constant{PARSE_COlNAMES}.
561
562
563The following example illustrates both ways.
564
565 \verbatiminput{sqlite3/converter_point.py}
566
567\subsubsection{Default adapters and converters}
568
569There are default adapters for the date and datetime types in the datetime
570module. They will be sent as ISO dates/ISO timestamps to SQLite.
571
572The default converters are registered under the name "date" for datetime.date
573and under the name "timestamp" for datetime.datetime.
574
575This way, you can use date/timestamps from Python without any additional
576fiddling in most cases. The format of the adapters is also compatible with the
577experimental SQLite date/time functions.
578
579The following example demonstrates this.
580
581 \verbatiminput{sqlite3/pysqlite_datetime.py}
582
583\subsection{Controlling Transactions \label{sqlite3-Controlling-Transactions}}
584
585By default, the \module{sqlite3} module opens transactions implicitly before a DML
586statement (INSERT/UPDATE/DELETE/REPLACE), and commits transactions implicitly
587before a non-DML, non-DQL statement (i. e. anything other than
588SELECT/INSERT/UPDATE/DELETE/REPLACE).
589
590So if you are within a transaction, and issue a command like \code{CREATE TABLE
591...}, \code{VACUUM}, \code{PRAGMA}, the \module{sqlite3} module will commit implicitly
592before executing that command. There are two reasons for doing that. The first
593is that some of these commands don't work within transactions. The other reason
594is that pysqlite needs to keep track of the transaction state (if a transaction
595is active or not).
596
597You can control which kind of "BEGIN" statements pysqlite implicitly executes
598(or none at all) via the \var{isolation_level} parameter to the
599\function{connect} call, or via the \member{isolation_level} property of
600connections.
601
602If you want \strong{autocommit mode}, then set \member{isolation_level} to None.
603
Thomas Wouters73e5a5b2006-06-08 15:35:45 +0000604Otherwise leave it at its default, which will result in a plain "BEGIN"
Thomas Wouters477c8d52006-05-27 19:21:47 +0000605statement, or set it to one of SQLite's supported isolation levels: DEFERRED,
606IMMEDIATE or EXCLUSIVE.
607
608As the \module{sqlite3} module needs to keep track of the transaction state, you should
609not use \code{OR ROLLBACK} or \code{ON CONFLICT ROLLBACK} in your SQL. Instead,
610catch the \exception{IntegrityError} and call the \method{rollback} method of
611the connection yourself.
612
613\subsection{Using pysqlite efficiently}
614
615\subsubsection{Using shortcut methods}
616
617Using the nonstandard \method{execute}, \method{executemany} and
618\method{executescript} methods of the \class{Connection} object, your code can
619be written more concisely, because you don't have to create the - often
620superfluous \class{Cursor} objects explicitly. Instead, the \class{Cursor}
621objects are created implicitly and these shortcut methods return the cursor
622objects. This way, you can for example execute a SELECT statement and iterate
623over it directly using only a single call on the \class{Connection} object.
624
625 \verbatiminput{sqlite3/shortcut_methods.py}
626
627\subsubsection{Accessing columns by name instead of by index}
628
629One cool feature of the \module{sqlite3} module is the builtin \class{sqlite3.Row} class
630designed to be used as a row factory.
631
632Rows wrapped with this class can be accessed both by index (like tuples) and
633case-insensitively by name:
634
635 \verbatiminput{sqlite3/rowclass.py}
636
637