quite some content to move over from the pysqlite manual, but it's a start now.
A \class{Connection} instance has the following attributes and methods:
\begin{memberdesc}{isolation_level}
- Get or set the current isolation level. None for autocommit mode or one
- of "DEFERRED", "IMMEDIATE" or "EXLUSIVE". See `5. Controlling
+ Get or set the current isolation level. None for autocommit mode or one
+ of "DEFERRED", "IMMEDIATE" or "EXLUSIVE". See `5. Controlling
Transactions`_ for a more detailed explanation.
\end{memberdesc}
This is a custom cursor class which must extend \class{sqlite3.Cursor}.
\end{methoddesc}
-TODO: execute*
+\begin{methoddesc}{execute}{sql, \optional{parameters}}
+This is a nonstandard shortcut that creates an intermediate cursor object by
+calling the cursor method, then calls the cursor's execute method with the
+parameters given.
+\end{methoddesc}
+
+\begin{methoddesc}{executemany}{sql, \optional{parameters}}
+This is a nonstandard shortcut that creates an intermediate cursor object by
+calling the cursor method, then calls the cursor's executemany method with the
+parameters given.
+\end{methoddesc}
+
+\begin{methoddesc}{executescript}{sql_script}
+This is a nonstandard shortcut that creates an intermediate cursor object by
+calling the cursor method, then calls the cursor's executescript method with the
+parameters given.
+\end{methoddesc}
+
+\begin{memberdesc}{row_factory}
+ You can change this attribute to a callable that accepts the cursor and
+ the original row as tuple and will return the real result row. This
+ way, you can implement more advanced ways of returning results, like
+ ones that can also access columns by name.
+
+ Example:
+
+ \verbatiminput{sqlite3/row_factory.py}
+
+ If the standard tuple types don't suffice for you, and you want name-based
+ access to columns, you should consider setting \member{row_factory} to the
+ highly-optimized pysqlite2.dbapi2.Row type. It provides both
+ index-based and case-insensitive name-based access to columns with almost
+ no memory overhead. Much better than your own custom dictionary-based
+ approach or even a db_row based solution.
+\end{memberdesc}
+
+\begin{memberdesc}{text_factory}
+ Using this attribute you can control what objects pysqlite returns for the
+ TEXT data type. By default, this attribute is set to ``unicode`` and
+ pysqlite will return Unicode objects for TEXT. If you want to return
+ bytestrings instead, you can set it to ``str``.
+
+ For efficiency reasons, there's also a way to return Unicode objects only
+ for non-ASCII data, and bytestrings otherwise. To activate it, set this
+ attribute to ``pysqlite2.dbapi2.OptimizedUnicode``.
+
+ You can also set it to any other callable that accepts a single bytestring
+ parameter and returns the result object.
+
+ See the following example code for illustration:
+
+ \verbatiminput{sqlite3/text_factory.py}
+\end{memberdesc}
+
+\begin{memberdesc}{total_changes}
+ Returns the total number of database rows that have be modified, inserted,
+ or deleted since the database connection was opened.
+\end{memberdesc}
+
+
+
+
+
+\subsection{Cursor Objects \label{Cursor-Objects}}
+
+A \class{Cursor} instance has the following attributes and methods:
+
+\begin{methoddesc}{execute}{sql, \optional{parameters}}
+
+Executes a SQL statement. The SQL statement may be parametrized (i. e.
+placeholders instead of SQL literals). The sqlite3 module supports two kinds of
+placeholders: question marks (qmark style) and named placeholders (named
+style).
+
+This example shows how to use parameters with qmark style:
+
+ \verbatiminput{sqlite3/execute_1.py}
+
+This example shows how to use the named style:
+
+ \verbatiminput{sqlite3/execute_2.py}
+
+ \method{execute} will only execute a single SQL statement. If you try to
+ execute more than one statement with it, it will raise a Warning. Use
+ \method{executescript} if want to execute multiple SQL statements with one
+ call.
+\end{methoddesc}
+
+
+\begin{methoddesc}{executemany}{sql, seq_of_parameters}
+Executes a SQL command against all parameter sequences or mappings found in the
+sequence \var{sql}. The \module{sqlite3} module also allows
+to use an iterator yielding parameters instead of a sequence.
+
+\verbatiminput{sqlite3/executemany_1.py}
+
+Here's a shorter example using a generator:
+
+\verbatiminput{sqlite3/executemany_2.py}
+\end{methoddesc}
+
+\begin{methoddesc}{executescript}{sql_script}
+
+This is a nonstandard convenience method for executing multiple SQL statements
+at once. It issues a COMMIT statement before, then executes the SQL script it
+gets as a parameter.
+
+\var{sql_script} can be a bytestring or a Unicode string.
+
+Example:
+
+\verbatiminput{sqlite3/executescript.py}
+\end{methoddesc}
+
+\begin{memberdesc}{rowcount}
+ Although the Cursors of the \module{sqlite3} module implement this
+ attribute, the database engine's own support for the determination of "rows
+ affected"/"rows selected" is quirky.
+
+ For \code{SELECT} statements, \member{rowcount} is always None because we cannot
+ determine the number of rows a query produced until all rows were fetched.
+
+ For \code{DELETE} statements, SQLite reports \member{rowcount} as 0 if you make a
+ \code{DELETE FROM table} without any condition.
+
+ For \method{executemany} statements, pysqlite sums up the number of
+ modifications into \member{rowcount}.
+
+ As required by the Python DB API Spec, the \member{rowcount} attribute "is -1
+ in case no executeXX() has been performed on the cursor or the rowcount
+ of the last operation is not determinable by the interface".
+\end{memberdesc}
+
--- /dev/null
+import sqlite3\r
+import datetime, time\r
+\r
+def adapt_datetime(ts):\r
+ return time.mktime(ts.timetuple())\r
+\r
+sqlite3.register_adapter(datetime.datetime, adapt_datetime)\r
+\r
+con = sqlite3.connect(":memory:")\r
+cur = con.cursor()\r
+\r
+now = datetime.datetime.now()\r
+cur.execute("select ?", (now,))\r
+print cur.fetchone()[0]\r
--- /dev/null
+import sqlite3\r
+\r
+class Point(object):\r
+ def __init__(self, x, y):\r
+ self.x, self.y = x, y\r
+\r
+ def __conform__(self, protocol):\r
+ if protocol is sqlite3.PrepareProtocol:\r
+ return "%f;%f" % (self.x, self.y)\r
+\r
+con = sqlite3.connect(":memory:")\r
+cur = con.cursor()\r
+\r
+p = Point(4.0, -3.2)\r
+cur.execute("select ?", (p,))\r
+print cur.fetchone()[0]\r
+\r
--- /dev/null
+import sqlite3\r
+\r
+class Point(object):\r
+ def __init__(self, x, y):\r
+ self.x, self.y = x, y\r
+\r
+def adapt_point(point):\r
+ return "%f;%f" % (point.x, point.y)\r
+\r
+sqlite3.register_adapter(Point, adapt_point)\r
+\r
+con = sqlite3.connect(":memory:")\r
+cur = con.cursor()\r
+\r
+p = Point(4.0, -3.2)\r
+cur.execute("select ?", (p,))\r
+print cur.fetchone()[0]\r
+\r
--- /dev/null
+import sqlite3\r
+\r
+def collate_reverse(string1, string2):\r
+ return -cmp(string1, string2)\r
+\r
+con = sqlite3.connect(":memory:")\r
+con.create_collation("reverse", collate_reverse)\r
+\r
+cur = con.cursor()\r
+cur.execute("create table test(x)")\r
+cur.executemany("insert into test(x) values (?)", [("a",), ("b",)])\r
+cur.execute("select x from test order by x collate reverse")\r
+for row in cur:\r
+ print row\r
+con.close()\r
--- /dev/null
+# A minimal SQLite shell for experiments
+
+import sqlite3
+
+con = sqlite3.connect(":memory:")
+con.isolation_level = None
+cur = con.cursor()
+
+buffer = ""
+
+print "Enter your SQL commands to execute in sqlite3."
+print "Enter a blank line to exit."
+
+while True:
+ line = raw_input()
+ if line == "":
+ break
+ buffer += line
+ if sqlite3.complete_statement(buffer):
+ try:
+ buffer = buffer.strip()
+ cur.execute(buffer)
+
+ if buffer.lstrip().upper().startswith("SELECT"):
+ print cur.fetchall()
+ except sqlite3.Error, e:
+ print "An error occured:", e.args[0]
+ buffer = ""
+
+con.close()
--- /dev/null
+import sqlite3\r
+\r
+con = sqlite3.connect("mydb")\r
--- /dev/null
+import sqlite3\r
+\r
+con = sqlite3.connect(":memory:")\r
--- /dev/null
+import sqlite3\r
+\r
+class Point(object):\r
+ def __init__(self, x, y):\r
+ self.x, self.y = x, y\r
+\r
+ def __repr__(self):\r
+ return "(%f;%f)" % (self.x, self.y)\r
+\r
+def adapt_point(point):\r
+ return "%f;%f" % (point.x, point.y)\r
+\r
+def convert_point(s):\r
+ x, y = map(float, s.split(";"))\r
+ return Point(x, y)\r
+\r
+# Register the adapter\r
+sqlite3.register_adapter(Point, adapt_point)\r
+\r
+# Register the converter\r
+sqlite3.register_converter("point", convert_point)\r
+\r
+p = Point(4.0, -3.2)\r
+\r
+#########################\r
+# 1) Using declared types\r
+con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_DECLTYPES)\r
+cur = con.cursor()\r
+cur.execute("create table test(p point)")\r
+\r
+cur.execute("insert into test(p) values (?)", (p,))\r
+cur.execute("select p from test")\r
+print "with declared types:", cur.fetchone()[0]\r
+cur.close()\r
+con.close()\r
+\r
+#######################\r
+# 1) Using column names\r
+con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_COLNAMES)\r
+cur = con.cursor()\r
+cur.execute("create table test(p)")\r
+\r
+cur.execute("insert into test(p) values (?)", (p,))\r
+cur.execute('select p as "p [point]" from test')\r
+print "with column names:", cur.fetchone()[0]\r
+cur.close()\r
+con.close()\r
--- /dev/null
+import sqlite3\r
+\r
+class CountCursorsConnection(sqlite3.Connection):\r
+ def __init__(self, *args, **kwargs):\r
+ sqlite3.Connection.__init__(self, *args, **kwargs)\r
+ self.numcursors = 0\r
+\r
+ def cursor(self, *args, **kwargs):\r
+ self.numcursors += 1\r
+ return sqlite3.Connection.cursor(self, *args, **kwargs)\r
+\r
+con = sqlite3.connect(":memory:", factory=CountCursorsConnection)\r
+cur1 = con.cursor()\r
+cur2 = con.cursor()\r
+print con.numcursors\r
--- /dev/null
+# Not referenced from the documentation, but builds the database file the other\r
+# code snippets expect.\r
+\r
+import sqlite3\r
+import os\r
+\r
+DB_FILE = "mydb"\r
+\r
+if os.path.exists(DB_FILE):\r
+ os.remove(DB_FILE)\r
+\r
+con = sqlite3.connect(DB_FILE)\r
+cur = con.cursor()\r
+cur.execute("""\r
+ create table people\r
+ (\r
+ name_last varchar(20),\r
+ age integer\r
+ )\r
+ """)\r
+\r
+cur.execute("insert into people (name_last, age) values ('Yeltsin', 72)")\r
+cur.execute("insert into people (name_last, age) values ('Putin', 51)")\r
+\r
+con.commit()\r
+\r
+cur.close()\r
+con.close()\r
--- /dev/null
+import sqlite3\r
+\r
+con = sqlite3.connect("mydb")\r
+\r
+cur = con.cursor()\r
+SELECT = "select name_last, age from people order by age, name_last"\r
+\r
+# 1. Iterate over the rows available from the cursor, unpacking the\r
+# resulting sequences to yield their elements (name_last, age):\r
+cur.execute(SELECT)\r
+for (name_last, age) in cur:\r
+ print '%s is %d years old.' % (name_last, age)\r
+\r
+# 2. Equivalently:\r
+cur.execute(SELECT)\r
+for row in cur:\r
+ print '%s is %d years old.' % (row[0], row[1])\r
--- /dev/null
+import sqlite3\r
+\r
+# Create a connection to the database file "mydb":\r
+con = sqlite3.connect("mydb")\r
+\r
+# Get a Cursor object that operates in the context of Connection con:\r
+cur = con.cursor()\r
+\r
+# Execute the SELECT statement:\r
+cur.execute("select * from people order by age")\r
+\r
+# Retrieve all rows as a sequence and print that sequence:\r
+print cur.fetchall()\r
--- /dev/null
+import sqlite3\r
+\r
+con = sqlite3.connect("mydb")\r
+\r
+cur = con.cursor()\r
+\r
+who = "Yeltsin"\r
+age = 72\r
+\r
+cur.execute("select name_last, age from people where name_last=? and age=?", (who, age))\r
+print cur.fetchone()\r
--- /dev/null
+import sqlite3\r
+\r
+con = sqlite3.connect("mydb")\r
+\r
+cur = con.cursor()\r
+\r
+who = "Yeltsin"\r
+age = 72\r
+\r
+cur.execute("select name_last, age from people where name_last=:who and age=:age",\r
+ {"who": who, "age": age})\r
+print cur.fetchone()\r
+\r
--- /dev/null
+import sqlite3\r
+\r
+con = sqlite3.connect("mydb")\r
+\r
+cur = con.cursor()\r
+\r
+who = "Yeltsin"\r
+age = 72\r
+\r
+cur.execute("select name_last, age from people where name_last=:who and age=:age",\r
+ locals())\r
+print cur.fetchone()\r
+\r
+\r
--- /dev/null
+import sqlite3\r
+\r
+class IterChars:\r
+ def __init__(self):\r
+ self.count = ord('a')\r
+\r
+ def __iter__(self):\r
+ return self\r
+\r
+ def next(self):\r
+ if self.count > ord('z'):\r
+ raise StopIteration\r
+ self.count += 1\r
+ return (chr(self.count - 1),) # this is a 1-tuple\r
+\r
+con = sqlite3.connect(":memory:")\r
+cur = con.cursor()\r
+cur.execute("create table characters(c)")\r
+\r
+theIter = IterChars()\r
+cur.executemany("insert into characters(c) values (?)", theIter)\r
+\r
+cur.execute("select c from characters")\r
+print cur.fetchall()\r
--- /dev/null
+import sqlite3\r
+\r
+def char_generator():\r
+ import string\r
+ for c in string.letters[:26]:\r
+ yield (c,)\r
+\r
+con = sqlite3.connect(":memory:")\r
+cur = con.cursor()\r
+cur.execute("create table characters(c)")\r
+\r
+cur.executemany("insert into characters(c) values (?)", char_generator())\r
+\r
+cur.execute("select c from characters")\r
+print cur.fetchall()\r
--- /dev/null
+import sqlite3\r
+\r
+con = sqlite3.connect(":memory:")\r
+cur = con.cursor()\r
+cur.executescript("""\r
+ create table person(\r
+ firstname,\r
+ lastname,\r
+ age\r
+ );\r
+\r
+ create table book(\r
+ title,\r
+ author,\r
+ published\r
+ );\r
+\r
+ insert into book(title, author, published)\r
+ values (\r
+ 'Dirk Gently''s Holistic Detective Agency\r
+ 'Douglas Adams',\r
+ 1987\r
+ );\r
+ """)\r
--- /dev/null
+import sqlite3\r
+\r
+con = sqlite3.connect("mydb")\r
+\r
+cur = con.cursor()\r
+\r
+newPeople = (\r
+ ('Lebed' , 53),\r
+ ('Zhirinovsky' , 57),\r
+ )\r
+\r
+for person in newPeople:\r
+ cur.execute("insert into people (name_last, age) values (?, ?)", person)\r
+\r
+# The changes will not be saved unless the transaction is committed explicitly:\r
+con.commit()\r
+\r
--- /dev/null
+import sqlite3\r
+import md5\r
+\r
+def md5sum(t):\r
+ return md5.md5(t).hexdigest()\r
+\r
+con = sqlite3.connect(":memory:")\r
+con.create_function("md5", 1, md5sum)\r
+cur = con.cursor()\r
+cur.execute("select md5(?)", ("foo",))\r
+print cur.fetchone()[0]\r
--- /dev/null
+import sqlite3\r
+\r
+class MySum:\r
+ def __init__(self):\r
+ self.count = 0\r
+\r
+ def step(self, value):\r
+ self.count += value\r
+\r
+ def finalize(self):\r
+ return self.count\r
+\r
+con = sqlite3.connect(":memory:")\r
+con.create_aggregate("mysum", 1, MySum)\r
+cur = con.cursor()\r
+cur.execute("create table test(i)")\r
+cur.execute("insert into test(i) values (1)")\r
+cur.execute("insert into test(i) values (2)")\r
+cur.execute("select mysum(i) from test")\r
+print cur.fetchone()[0]\r
--- /dev/null
+import sqlite3\r
+import datetime\r
+\r
+con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_COLNAMES)\r
+cur = con.cursor()\r
+cur.execute('select ? as "x [timestamp]"', (datetime.datetime.now(),))\r
+dt = cur.fetchone()[0]\r
+print dt, type(dt)\r
--- /dev/null
+import sqlite3\r
+import datetime\r
+\r
+con = sqlite3.connect(":memory:", detect_types=sqlite3.PARSE_DECLTYPES|sqlite3.PARSE_COLNAMES)\r
+cur = con.cursor()\r
+cur.execute("create table test(d date, ts timestamp)")\r
+\r
+today = datetime.date.today()\r
+now = datetime.datetime.now()\r
+\r
+cur.execute("insert into test(d, ts) values (?, ?)", (today, now))\r
+cur.execute("select d, ts from test")\r
+row = cur.fetchone()\r
+print today, "=>", row[0], type(row[0])\r
+print now, "=>", row[1], type(row[1])\r
+\r
+cur.execute('select current_date as "d [date]", current_timestamp as "ts [timestamp]"')\r
+row = cur.fetchone()\r
+print "current_date", row[0], type(row[0])\r
+print "current_timestamp", row[1], type(row[1])\r
--- /dev/null
+import sqlite3\r
+\r
+def dict_factory(cursor, row):\r
+ d = {}\r
+ for idx, col in enumerate(cursor.description):\r
+ d[col[0]] = row[idx]\r
+ return d\r
+\r
+con = sqlite3.connect(":memory:")\r
+con.row_factory = dict_factory\r
+cur = con.cursor()\r
+cur.execute("select 1 as a")\r
+print cur.fetchone()["a"]\r
--- /dev/null
+import sqlite3
+
+con = sqlite3.connect("mydb")
+con.row_factory = sqlite3.Row
+
+cur = con.cursor()
+cur.execute("select name_last, age from people")
+for row in cur:
+ assert row[0] == row["name_last"]
+ assert row["name_last"] == row["nAmE_lAsT"]
+ assert row[1] == row["age"]
+ assert row[1] == row["AgE"]
--- /dev/null
+import sqlite3
+
+# The shared cache is only available in SQLite versions 3.3.3 or later
+# See the SQLite documentaton for details.
+
+sqlite3.enable_shared_cache(True)
--- /dev/null
+import sqlite3
+
+persons = [
+ ("Hugo", "Boss"),
+ ("Calvin", "Klein")
+ ]
+
+con = sqlite3.connect(":memory:")
+
+# Create the table
+con.execute("create table person(firstname, lastname)")
+
+# Fill the table
+con.executemany("insert into person(firstname, lastname) values (?, ?)", persons)
+
+# Print the table contents
+for row in con.execute("select firstname, lastname from person"):
+ print row
+
+# Using a dummy WHERE clause to not let SQLite take the shortcut table deletes.
+print "I just deleted", con.execute("delete from person where 1=1").rowcount, "rows"
+
--- /dev/null
+import sqlite3\r
+\r
+FIELD_MAX_WIDTH = 20\r
+TABLE_NAME = 'people'\r
+SELECT = 'select * from %s order by age, name_last' % TABLE_NAME\r
+\r
+con = sqlite3.connect("mydb")\r
+\r
+cur = con.cursor()\r
+cur.execute(SELECT)\r
+\r
+# Print a header.\r
+for fieldDesc in cur.description:\r
+ print fieldDesc[0].ljust(FIELD_MAX_WIDTH) ,\r
+print # Finish the header with a newline.\r
+print '-' * 78\r
+\r
+# For each row, print the value of each field left-justified within\r
+# the maximum possible width of that field.\r
+fieldIndices = range(len(cur.description))\r
+for row in cur:\r
+ for fieldIndex in fieldIndices:\r
+ fieldValue = str(row[fieldIndex])\r
+ print fieldValue.ljust(FIELD_MAX_WIDTH) ,\r
+\r
+ print # Finish the row with a newline.\r
--- /dev/null
+import sqlite3
+
+con = sqlite3.connect(":memory:")
+cur = con.cursor()
+
+# Create the table
+con.execute("create table person(lastname, firstname)")
+
+AUSTRIA = u"\xd6sterreich"
+
+# by default, rows are returned as Unicode
+cur.execute("select ?", (AUSTRIA,))
+row = cur.fetchone()
+assert row[0] == AUSTRIA
+
+# but we can make pysqlite always return bytestrings ...
+con.text_factory = str
+cur.execute("select ?", (AUSTRIA,))
+row = cur.fetchone()
+assert type(row[0]) == str
+# the bytestrings will be encoded in UTF-8, unless you stored garbage in the
+# database ...
+assert row[0] == AUSTRIA.encode("utf-8")
+
+# we can also implement a custom text_factory ...
+# here we implement one that will ignore Unicode characters that cannot be
+# decoded from UTF-8
+con.text_factory = lambda x: unicode(x, "utf-8", "ignore")
+cur.execute("select ?", ("this is latin1 and would normally create errors" + u"\xe4\xf6\xfc".encode("latin1"),))
+row = cur.fetchone()
+assert type(row[0]) == unicode
+
+# pysqlite offers a builtin optimized text_factory that will return bytestring
+# objects, if the data is in ASCII only, and otherwise return unicode objects
+con.text_factory = sqlite3.OptimizedUnicode
+cur.execute("select ?", (AUSTRIA,))
+row = cur.fetchone()
+assert type(row[0]) == unicode
+
+cur.execute("select ?", ("Germany",))
+row = cur.fetchone()
+assert type(row[0]) == str
+