1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
|
Basic module usage
==================
.. sectionauthor:: Daniele Varrazzo <daniele.varrazzo@gmail.com>
.. index::
pair: Example; Usage
The basic Psycopg usage is common to all the database adapters implementing
the |DBAPI|_ protocol. Here is an interactive session showing some of the
basic commands::
>>> import psycopg2
# Connect to an existing database
>>> conn = psycopg2.connect("dbname=test user=postgres")
# Open a cursor to perform database operations
>>> cur = conn.cursor()
# Execute a command: this creates a new table
>>> cur.execute("CREATE TABLE test (id serial PRIMARY KEY, num integer, data varchar);")
# Pass data to fill a query placeholders and let Psycopg perform
# the correct conversion (no more SQL injections!)
>>> cur.execute("INSERT INTO test (num, data) VALUES (%s, %s)",
... (100, "abc'def"))
# Query the database and obtain data as Python objects
>>> cur.execute("SELECT * FROM test;")
>>> cur.fetchone()
(1, 100, "abc'def")
# Make the changes to the database persistent
>>> conn.commit()
# Close communication with the database
>>> cur.close()
>>> conn.close()
The main entry point of Psycopg are:
- The function :func:`~psycopg2.connect` creates a new database session and
returns a new :class:`connection` instance.
- The class :class:`connection` encapsulates a database session. It allows to:
- create new :class:`cursor`\s using the :meth:`~connection.cursor` method to
execute database commands and queries,
- terminate the session using the methods :meth:`~connection.commit` or
:meth:`~connection.rollback`.
- The class :class:`cursor` allows interaction with the database:
- send commands to the database using methods such as :meth:`~cursor.execute`
and :meth:`~cursor.executemany`,
- retrieve data from the database using methods such as
:meth:`~cursor.fetchone`, :meth:`~cursor.fetchmany`,
:meth:`~cursor.fetchall`.
.. index::
pair: Query; Parameters
.. _query-parameters:
Passing parameters to SQL queries
---------------------------------
Psycopg casts Python variables to SQL literals by type. Many standard Python types
are already `adapted to the correct SQL representation`__.
.. __: python-types-adaptation_
Example: the Python function call::
>>> cur.execute(
... """INSERT INTO some_table (an_int, a_date, a_string)
... VALUES (%s, %s, %s);""",
... (10, datetime.date(2005, 11, 18), "O'Reilly"))
is converted into the SQL command::
INSERT INTO some_table (an_int, a_date, a_string)
VALUES (10, '2005-11-18', 'O''Reilly');
Named arguments are supported too using :samp:`%({name})s` placeholders.
Using named arguments the values can be passed to the query in any order and
many placeholder can use the same values::
>>> cur.execute(
... """INSERT INTO some_table (an_int, a_date, another_date, a_string)
... VALUES (%(int)s, %(date)s, %(date)s, %(str)s);""",
... {'int': 10, 'str': "O'Reilly", 'date': datetime.date(2005, 11, 18)})
While the mechanism resembles regular Python strings manipulation, there are a
few subtle differences you should care about when passing parameters to a
query:
- The Python string operator ``%`` is not used: the :meth:`~cursor.execute`
method accepts a tuple or dictionary of values as second parameter.
|sql-warn|__.
.. |sql-warn| replace:: **Never** use ``%`` or ``+`` to merge values
into queries
.. __: sql-injection_
- The variables placeholder must *always be a* ``%s``, even if a different
placeholder (such as a ``%d`` for integers or ``%f`` for floats) may look
more appropriate::
>>> cur.execute("INSERT INTO numbers VALUES (%d)", (42,)) # WRONG
>>> cur.execute("INSERT INTO numbers VALUES (%s)", (42,)) # correct
- For positional variables binding, *the second argument must always be a
tuple*, even if it contains a single variable. And remember that Python
requires a comma to create a single element tuple::
>>> cur.execute("INSERT INTO foo VALUES (%s)", "bar") # WRONG
>>> cur.execute("INSERT INTO foo VALUES (%s)", ("bar")) # WRONG
>>> cur.execute("INSERT INTO foo VALUES (%s)", ("bar",)) # correct
- Only variable values should be bound via this method: it shouldn't be used
to set table or field names. For these elements, ordinary string formatting
should be used before running :meth:`~cursor.execute`.
.. index:: Security, SQL injection
.. _sql-injection:
The problem with the query parameters
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
The SQL representation for many data types is often not the same of the Python
string representation. The classic example is with single quotes in
strings: SQL uses them as string constants bounds and requires them to be
escaped, whereas in Python single quotes can be left unescaped in strings
bounded by double quotes. For this reason a naïve approach to the composition
of query strings, e.g. using string concatenation, is a recipe for terrible
problems::
>>> SQL = "INSERT INTO authors (name) VALUES ('%s');" # NEVER DO THIS
>>> data = ("O'Reilly", )
>>> cur.execute(SQL % data) # THIS WILL FAIL MISERABLY
ProgrammingError: syntax error at or near "Reilly"
LINE 1: INSERT INTO authors (name) VALUES ('O'Reilly')
^
If the variable containing the data to be sent to the database comes from an
untrusted source (e.g. a form published on a web site) an attacker could
easily craft a malformed string, either gaining access to unauthorized data or
performing destructive operations on the database. This form of attack is
called `SQL injection`_ and is known to be one of the most widespread forms of
attack to servers. Before continuing, please print `this page`__ as a memo and
hang it onto your desk.
.. _SQL injection: http://en.wikipedia.org/wiki/SQL_injection
.. __: http://xkcd.com/327/
Psycopg can `convert automatically Python objects into and from SQL
literals`__: using this feature your code will result more robust and
reliable. It is really the case to stress this point:
.. __: python-types-adaptation_
.. warning::
Never, **never**, **NEVER** use Python string concatenation (``+``) or
string parameters interpolation (``%``) to pass variables to a SQL query
string. Not even at gunpoint.
The correct way to pass variables in a SQL command is using the second
argument of the :meth:`~cursor.execute` method::
>>> SQL = "INSERT INTO authors (name) VALUES (%s);" # Notice: no quotes
>>> data = ("O'Reilly", )
>>> cur.execute(SQL, data) # Notice: no % operator
.. index::
pair: Objects; Adaptation
single: Data types; Adaptation
.. _python-types-adaptation:
Adaptation of Python values to SQL types
----------------------------------------
Many standards Python types are adapted into SQL and returned as Python
objects when a query is executed.
If you need to convert other Python types to and from PostgreSQL data types,
see :ref:`adapting-new-types` and :ref:`type-casting-from-sql-to-python`. You
can also find a few other specialized adapters in the :mod:`psycopg2.extras`
module.
In the following examples the method :meth:`~cursor.mogrify` is used to show
the SQL string that would be sent to the database.
.. index::
single: None; Adaptation
single: NULL; Adaptation
single: Boolean; Adaptation
- Python ``None`` and boolean values are converted into the proper SQL
literals::
>>> cur.mogrify("SELECT %s, %s, %s;", (None, True, False))
>>> 'SELECT NULL, true, false;'
.. index::
single: Integer; Adaptation
single: Float; Adaptation
single: Decimal; Adaptation
- Numeric objects: :class:`!int`, :class:`!long`, :class:`!float`,
:class:`!Decimal` are converted in the PostgreSQL numerical representation::
>>> cur.mogrify("SELECT %s, %s, %s, %s;", (10, 10L, 10.0, Decimal("10.00")))
>>> 'SELECT 10, 10, 10.0, 10.00;'
.. index::
single: Strings; Adaptation
single: Unicode; Adaptation
single: Buffer; Adaptation
single: bytea; Adaptation
single: Binary string
- String types: :class:`!str`, :class:`!unicode` are converted in SQL string
syntax. :class:`!buffer` is converted in PostgreSQL binary string syntax,
suitable for :sql:`bytea` fields. When reading textual fields, either
:class:`!str` or :class:`!unicode` can be received: see
:ref:`unicode-handling`.
.. index::
single: Date objects; Adaptation
single: Time objects; Adaptation
single: Interval objects; Adaptation
single: mx.DateTime; Adaptation
- Date and time objects: builtin :class:`!datetime`, :class:`!date`,
:class:`!time`. :class:`!timedelta` are converted into PostgreSQL's
:sql:`timestamp`, :sql:`date`, :sql:`time`, :sql:`interval` data types.
Time zones are supported too. The Egenix `mx.DateTime`_ objects are adapted
the same way::
>>> dt = datetime.datetime.now()
>>> dt
datetime.datetime(2010, 2, 8, 1, 40, 27, 425337)
>>> cur.mogrify("SELECT %s, %s, %s;", (dt, dt.date(), dt.time()))
"SELECT '2010-02-08T01:40:27.425337', '2010-02-08', '01:40:27.425337';"
>>> cur.mogrify("SELECT %s;", (dt - datetime.datetime(2010,1,1),))
"SELECT '38 days 6027.425337 seconds';"
.. index::
single: Array; Adaptation
single: Lists; Adaptation
- Python lists are converted into PostgreSQL :sql:`ARRAY`\ s::
>>> cur.mogrify("SELECT %s;", ([10, 20, 30], ))
'SELECT ARRAY[10, 20, 30];'
.. index::
single: Tuple; Adaptation
single: IN operator
- Python tuples are converted in a syntax suitable for the SQL :sql:`IN`
operator::
>>> cur.mogrify("SELECT %s IN %s;", (10, (10, 20, 30)))
'SELECT 10 IN (10, 20, 30);'
.. note::
SQL doesn't allow an empty list in the IN operator, so your code should
guard against empty tuples.
.. note::
The IN adapter is automatically registered when the
:mod:`~psycopg2.extensions` module is imported. This behaviour may change
in the future and the adapter will probably be always active.
.. versionadded:: 2.0.6
the tuple :sql:`IN` adaptation.
.. index::
single: Unicode
.. _unicode-handling:
Unicode handling
^^^^^^^^^^^^^^^^
Psycopg can exchange Unicode data with a PostgreSQL database. Python
:class:`!unicode` objects are automatically *encoded* in the client encoding
defined on the database connection (the `PostgreSQL encoding`__, available in
:attr:`connection.encoding`, is translated into a `Python codec`__ using an
:data:`~psycopg2.extensions.encodings` mapping)::
>>> print u, type(u)
àèìòù€ <type 'unicode'>
>>> cur.execute("INSERT INTO test (num, data) VALUES (%s,%s);", (74, u))
.. __: http://www.postgresql.org/docs/8.4/static/multibyte.html
.. __: http://docs.python.org/library/codecs.html#standard-encodings
When reading data from the database, the strings returned are usually 8 bit
:class:`!str` objects encoded in the database client encoding::
>>> print conn.encoding
UTF8
>>> cur.execute("SELECT data FROM test WHERE num = 74")
>>> x = cur.fetchone()[0]
>>> print x, type(x), repr(x)
àèìòù€ <type 'str'> '\xc3\xa0\xc3\xa8\xc3\xac\xc3\xb2\xc3\xb9\xe2\x82\xac'
>>> conn.set_client_encoding('LATIN9')
>>> cur.execute("SELECT data FROM test WHERE num = 74")
>>> x = cur.fetchone()[0]
>>> print type(x), repr(x)
<type 'str'> '\xe0\xe8\xec\xf2\xf9\xa4'
In order to obtain :class:`!unicode` objects instead, it is possible to
register a typecaster so that PostgreSQL textual types are automatically
*decoded* using the current client encoding::
>>> psycopg2.extensions.register_type(psycopg2.extensions.UNICODE, cur)
>>> cur.execute("SELECT data FROM test WHERE num = 74")
>>> x = cur.fetchone()[0]
>>> print x, type(x), repr(x)
àèìòù€ <type 'unicode'> u'\xe0\xe8\xec\xf2\xf9\u20ac'
In the above example, the :data:`~psycopg2.extensions.UNICODE` typecaster is
registered only on the cursor. It is also possible to register typecasters on
the connection or globally: see the function
:func:`~psycopg2.extensions.register_type` and
:ref:`type-casting-from-sql-to-python` for details.
.. note::
If you want to receive uniformly all your database input in Unicode, you
can register the related typecasters globally as soon as Psycopg is
imported::
import psycopg2
import psycopg2.extensions
psycopg2.extensions.register_type(psycopg2.extensions.UNICODE)
psycopg2.extensions.register_type(psycopg2.extensions.UNICODEARRAY)
and then forget about this story.
.. index:: Transaction, Begin, Commit, Rollback, Autocommit
.. _transactions-control:
Transactions control
--------------------
In Psycopg transactions are handled by the :class:`connection` class. By
default, the first time a command is sent to the database (using one of the
:class:`cursor`\ s created by the connection), a new transaction is created.
The following database commands will be executed in the context of the same
transaction -- not only the commands issued by the first cursor, but the ones
issued by all the cursors created by the same connection. Should any command
fail, the transaction will be aborted and no further command will be executed
until a call to the :meth:`connection.rollback` method.
The connection is responsible to terminate its transaction, calling either the
:meth:`~connection.commit` or :meth:`~connection.rollback` method. Committed
changes are immediately made persistent into the database. Closing the
connection using the :meth:`~connection.close` method or destroying the
connection object (calling :meth:`!__del__` or letting it fall out of scope)
will result in an implicit :meth:`!rollback` call.
It is possible to set the connection in *autocommit* mode: this way all the
commands executed will be immediately committed and no rollback is possible. A
few commands (e.g. :sql:`CREATE DATABASE`, :sql:`VACUUM`...) require to be run
outside any transaction: in order to be able to run these commands from
Psycopg, the session must be in autocommit mode. Read the documentation for
:meth:`connection.set_isolation_level` to know how to change the commit mode.
.. index::
pair: Server side; Cursor
pair: Named; Cursor
pair: DECLARE; SQL command
pair: FETCH; SQL command
pair: MOVE; SQL command
.. _server-side-cursors:
Server side cursors
-------------------
When a database query is executed, the Psycopg :class:`cursor` usually fetches
all the records returned by the backend, transferring them to the client
process. If the query returned an huge amount of data, a proportionally large
amount of memory will be allocated by the client.
If the dataset is too large to be practically handled on the client side, it is
possible to create a *server side* cursor. Using this kind of cursor it is
possible to transfer to the client only a controlled amount of data, so that a
large dataset can be examined without keeping it entirely in memory.
Server side cursor are created in PostgreSQL using the |DECLARE|_ command and
subsequently handled using :sql:`MOVE`, :sql:`FETCH` and :sql:`CLOSE` commands.
Psycopg wraps the database server side cursor in *named cursors*. A named
cursor is created using the :meth:`~connection.cursor` method specifying the
`name` parameter. Such cursor will behave mostly like a regular cursor,
allowing the user to move in the dataset using the :meth:`~cursor.scroll`
methog and to read the data using :meth:`~cursor.fetchone` and
:meth:`~cursor.fetchmany` methods.
.. |DECLARE| replace:: :sql:`DECLARE`
.. _DECLARE: http://www.postgresql.org/docs/8.4/static/sql-declare.html
.. index:: Thread safety, Multithread
.. _thread-safety:
Thread safety
-------------
The Psycopg module is *thread-safe*: threads can access the same database
using separate session (by creating a :class:`connection` per thread) or using
the same session (accessing to the same connection and creating separate
:class:`cursor`\ s). In |DBAPI|_ parlance, Psycopg is *level 2 thread safe*.
.. index::
pair: COPY; SQL command
.. _copy:
Using COPY TO and COPY FROM
---------------------------
Psycopg :class:`cursor` objects provide an interface to the efficient
PostgreSQL |COPY|__ command to move data from files to tables and back.
The methods exposed are:
:meth:`~cursor.copy_from`
Reads data *from* a file-like object appending them to a database table
(:sql:`COPY table FROM file` syntax). The source file must have both
:meth:`!read` and :meth:`!readline` method.
:meth:`~cursor.copy_to`
Writes the content of a table *to* a file-like object (:sql:`COPY table TO
file` syntax). The target file must have a :meth:`write` method.
:meth:`~cursor.copy_expert`
Allows to handle more specific cases and to use all the :sql:`COPY`
features available in PostgreSQL.
Please refer to the documentation of the single methods for details and
examples.
.. |COPY| replace:: :sql:`COPY`
.. __: http://www.postgresql.org/docs/8.4/static/sql-copy.html
.. index::
single: Large objects
.. _large-objects:
Access to PostgreSQL large objects
----------------------------------
PostgreSQL offers support to `large objects`__, which provide stream-style
access to user data that is stored in a special large-object structure. They
are useful with data values too large to be manipulated conveniently as a
whole.
.. __: http://www.postgresql.org/docs/8.4/static/largeobjects.html
Psycopg allows access to the large object using the
:class:`~psycopg2.extensions.lobject` class. Objects are generated using the
:meth:`connection.lobject` factory method.
Psycopg large object support efficient import/export with file system files
using the |lo_import|_ and |lo_export|_ libpq functions.
.. |lo_import| replace:: :func:`!lo_import`
.. _lo_import: http://www.postgresql.org/docs/8.4/static/lo-interfaces.html#AEN36307
.. |lo_export| replace:: :func:`!lo_export`
.. _lo_export: http://www.postgresql.org/docs/8.4/static/lo-interfaces.html#AEN36330
|