Cursors (executing SQL)

A cursor encapsulates a SQL query and returning results. You only need an explicit cursor if you want more information or control over execution. Using Connection.execute() or Connection.executemany() will automatically obtain a cursor behind the scenes.

If you need a cursor you should call cursor() on your database:

db=apsw.Connection("databasefilename")
cursor=db.cursor()

A cursor executes SQL:

cursor.execute("create table example(title, isbn)")

You can also read data back. The row is returned as a tuple of the column values:

for row in cursor.execute("select * from example"):
   print(row)

There are two ways of supplying data to a query. The really bad way is to compose a string:

sql="insert into example values('%s', %d)" % ("string", 8390823904)
cursor.execute(sql)

If there were any single quotes in string then you would have invalid syntax. Additionally this is how SQL injection attacks happen. Instead you should use bindings:

sql="insert into example values(?, ?)"
cursor.execute(sql, ("string", 8390823904))

# You can also use dictionaries (with colon, $, or @ before names)
sql="insert into example values(:title, :isbn)"
cursor.execute(sql, {"title": "string", "isbn": 8390823904})

# You can use local variables as the dictionary
title="..."
isbn="...."
cursor.execute(sql, locals())

Cursors are cheap. Use as many as you need. It is safe to use them across threads, such as calling execute() in one thread, passing the cursor to another thread that then calls next. The only thing you can’t do is call methods at exactly the same time on the same cursor in two different threads - eg trying to call execute() in both at the same time, or execute() in one and next in another. (If you do attempt this, it will be detected and ThreadingViolationError will be raised.)

Behind the scenes a Cursor maps to a SQLite statement. APSW maintains a cache so that the mapping is very fast, and the SQLite objects are reused when possible.

A unique feature of APSW is that your query can be multiple semi-colon separated statements. For example:

cursor.execute("select ... ; insert into ... ; update ... ; select ...")

Note

SQLite fetches data as it is needed. If table example had 10 million rows it would only get the next row as requested. This code would not work as expected:

for row in cursor.execute("select * from example"):
   cursor.execute("insert .....")

The nested execute() would start a new query abandoning any remaining results from the SELECT cursor. There are two ways to work around this. Use a different cursor:

for row in cursor1.execute("select * from example"):
   cursor2.execute("insert ...")

You can also get all the rows immediately by filling in a list:

rows=list( cursor.execute("select * from example") )
for row in rows:
   cursor.execute("insert ...")

This last approach is recommended since you don’t have to worry about the database changing while doing the select. You should also understand transactions and where to put the transaction boundaries.

Note

Cursors on the same Connection are not isolated from each other. Anything done on one cursor is immediately visible to all other Cursors on the same connection. This still applies if you start transactions. Connections are isolated from each other with cursors on other connections not seeing changes until they are committed.

Cursor class

class Cursor

You obtain cursors by calling Connection.cursor().

Cursor.__iter__(self: Cursor) Cursor

Cursors are iterators

Cursor.__next__(self: Cursor) Any

Cursors are iterators

Cursor.close(force: bool = False) None

It is very unlikely you will need to call this method. It exists because older versions of SQLite required all Connection/Cursor activity to be confined to the same thread. That is no longer the case. Cursors are automatically garbage collected and when there are none left will allow the connection to be garbage collected if it has no other references.

A cursor is open if there are remaining statements to execute (if your query included multiple statements), or if you called executemany() and not all of the sequenceofbindings have been used yet.

Parameters

force – If False then you will get exceptions if there is remaining work to do be in the Cursor such as more statements to execute, more data from the executemany binding sequence etc. If force is True then all remaining work and state information will be silently discarded.

Cursor.connection: Connection

Connection this cursor is using

Cursor.description: Tuple[Tuple[str, str, None, None, None, None, None], ...]

Based on the DB-API cursor property, this returns the same as getdescription() but with 5 Nones appended. See also APSW issue 131.

Cursor.description_full: Tuple[Tuple[str, str, str, str, str], ...]

Only present if SQLITE_ENABLE_COLUMN_METADATA was defined at compile time.

Returns all information about the query result columns. In addition to the name and declared type, you also get the database name, table name, and origin name.

Calls:
Cursor.exectrace: Optional[ExecTracer]

Called with the cursor, statement and bindings for each execute() or executemany() on this cursor.

If callable is None then any existing execution tracer is unregistered.

Cursor.execute(statements: str, bindings: Optional[Bindings] = None, *, can_cache: bool = True, prepare_flags: int = 0) Cursor

Executes the statements using the supplied bindings. Execution returns when the first row is available or all statements have completed.

Parameters
  • statements – One or more SQL statements such as select * from books or begin; insert into books ...; select last_insert_rowid(); end.

  • bindings – If supplied should either be a sequence or a dictionary. Each item must be one of the supported types

  • can_cache – If False then the statement cache will not be used to find an already prepared query, nor will it be placed in the cache after execution

  • prepare_flagsflags passed to sqlite_prepare_v3

If you use numbered bindings in the query then supply a sequence. Any sequence will work including lists and iterators. For example:

cursor.execute("insert into books values(?,?)", ("title", "number"))

Note

A common gotcha is wanting to insert a single string but not putting it in a tuple:

cursor.execute("insert into books values(?)", "a title")

The string is a sequence of 8 characters and so it will look like you are supplying 8 bindings when only one is needed. Use a one item tuple with a trailing comma like this:

cursor.execute("insert into books values(?)", ("a title",) )

If you used names in the statement then supply a dictionary as the binding. It is ok to be missing entries from the dictionary - None/null will be used. For example:

cursor.execute("insert into books values(:title, :isbn, :rating)",
     {"title": "book title", "isbn": 908908908})

The return is the cursor object itself which is also an iterator. This allows you to write:

for row in cursor.execute("select * from books"):
   print(row)
Raises
  • TypeError – The bindings supplied were neither a dict nor a sequence

  • BindingsError – You supplied too many or too few bindings for the statements

  • IncompleteExecutionError – There are remaining unexecuted queries from your last execute

See also

Calls:
Cursor.executemany(statements: str, sequenceofbindings: Sequence[Bindings], *, can_cache: bool = True, prepare_flags: int = 0) Cursor

This method is for when you want to execute the same statements over a sequence of bindings. Conceptually it does this:

for binding in sequenceofbindings:
    cursor.execute(statements, binding)

Example:

rows=(  (1, 7),
        (2, 23),
        (4, 92),
        (12, 12) )

cursor.executemany("insert into nums values(?,?)", rows)

The return is the cursor itself which acts as an iterator. Your statements can return data. See execute() for more information.

Cursor.expanded_sql: str

The SQL text with bound parameters expanded. For example:

execute("select ?, ?", (3, "three"))

would return:

select 3, 'three'

Note that while SQLite supports nulls in strings, their implementation of sqlite3_expanded_sql stops at the first null.

Calls: sqlite3_expanded_sql

Cursor.fetchall() list[Tuple[SQLiteValue, ...]]

Returns all remaining result rows as a list. This method is defined in DBAPI. It is a longer way of doing list(cursor).

Cursor.fetchone() Optional[Any]

Returns the next row of data or None if there are no more rows.

Cursor.getconnection() Connection

Returns the connection this cursor is using

Cursor.getdescription() Tuple[Tuple[str, str], ...]

If you are trying to get information about a table or view, then pragma table_info is better.

Returns a tuple describing each column in the result row. The return is identical for every row of the results. You can only call this method once you have started executing a statement and before you have finished:

# This will error
cursor.getdescription()

for row in cursor.execute("select ....."):
   # this works
   print (cursor.getdescription())
   print (row)

The information about each column is a tuple of (column_name, declared_column_type). The type is what was declared in the CREATE TABLE statement - the value returned in the row will be whatever type you put in for that row and column. (This is known as manifest typing which is also the way that Python works. The variable a could contain an integer, and then you could put a string in it. Other static languages such as C or other SQL databases only let you put one type in - eg a could only contain an integer or a string, but never both.)

Example:

cursor.execute("create table books(title string, isbn number, wibbly wobbly zebra)")
cursor.execute("insert into books values(?,?,?)", (97, "fjfjfj", 3.7))
cursor.execute("insert into books values(?,?,?)", ("fjfjfj", 3.7, 97))

for row in cursor.execute("select * from books"):
   print (cursor.getdescription())
   print (row)

Output:

# row 0 - description
(('title', 'string'), ('isbn', 'number'), ('wibbly', 'wobbly zebra'))
# row 0 - values
(97, 'fjfjfj', 3.7)
# row 1 - description
(('title', 'string'), ('isbn', 'number'), ('wibbly', 'wobbly zebra'))
# row 1 - values
('fjfjfj', 3.7, 97)
Calls:
Cursor.getexectrace() Optional[ExecTracer]

Returns the currently installed execution tracer

See also

Cursor.getrowtrace() Optional[RowTracer]

Returns the currently installed (via setrowtrace()) row tracer.

See also

Cursor.is_explain: int

Returns 0 if executing a normal query, 1 if it is an EXPLAIN query, and 2 if an EXPLAIN QUERY PLAN query.

Calls: sqlite3_stmt_isexplain

Cursor.is_readonly: bool

Returns True if the current query does not change the database.

Note that called functions, virtual tables etc could make changes though.

Calls: sqlite3_stmt_readonly

Cursor.rowtrace: Optional[RowTracer]

Called with cursor and row being returned. You can change the data that is returned or cause the row to be skipped altogether.

If callable is None then any existing row tracer is unregistered.

Cursor.setexectrace(callable: Optional[ExecTracer]) None

Sets the execution tracer

Cursor.setrowtrace(callable: Optional[RowTracer]) None

Sets the row tracer