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