README.rst 44 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966967968969970971972973974975976977978979980981982983984985986987988989990991992993994995996997998999100010011002100310041005100610071008100910101011101210131014101510161017101810191020102110221023102410251026102710281029103010311032103310341035103610371038103910401041104210431044104510461047104810491050105110521053105410551056105710581059106010611062106310641065106610671068106910701071107210731074107510761077107810791080108110821083108410851086108710881089109010911092109310941095109610971098109911001101110211031104110511061107110811091110111111121113111411151116111711181119112011211122112311241125112611271128112911301131113211331134113511361137113811391140114111421143114411451146114711481149115011511152115311541155115611571158115911601161116211631164116511661167116811691170117111721173117411751176117711781179118011811182118311841185118611871188118911901191119211931194119511961197119811991200120112021203120412051206120712081209121012111212121312141215121612171218121912201221122212231224122512261227122812291230123112321233123412351236123712381239124012411242124312441245124612471248124912501251125212531254125512561257125812591260126112621263126412651266126712681269127012711272127312741275127612771278127912801281128212831284128512861287128812891290129112921293129412951296129712981299130013011302130313041305130613071308130913101311131213131314131513161317131813191320132113221323132413251326132713281329133013311332133313341335133613371338133913401341134213431344134513461347134813491350135113521353135413551356135713581359136013611362136313641365136613671368136913701371137213731374137513761377137813791380138113821383138413851386138713881389139013911392139313941395139613971398139914001401140214031404140514061407
  1. ======
  2. pg8000
  3. ======
  4. .. |ssl.SSLContext| replace:: ``ssl.SSLContext``
  5. .. _ssl.SSLContext: https://docs.python.org/3/library/ssl.html#ssl.SSLContext
  6. .. |ssl.create_default_context()| replace:: ``ssl.create_default_context()``
  7. .. _ssl.create_default_context(): https://docs.python.org/3/library/ssl.html#ssl.create_default_context
  8. pg8000 is a pure-`Python <https://www.python.org/>`_
  9. `PostgreSQL <http://www.postgresql.org/>`_ driver that complies with
  10. `DB-API 2.0 <http://www.python.org/dev/peps/pep-0249/>`_. It is tested on Python
  11. versions 3.8+, on CPython and PyPy, and PostgreSQL versions 12+. pg8000's name comes
  12. from the belief that it is probably about the 8000th PostgreSQL interface for Python.
  13. pg8000 is distributed under the BSD 3-clause license.
  14. All bug reports, feature requests and contributions are welcome at
  15. `http://github.com/tlocke/pg8000/ <http://github.com/tlocke/pg8000/>`_.
  16. .. image:: https://github.com/tlocke/pg8000/workflows/pg8000/badge.svg
  17. :alt: Build Status
  18. .. contents:: Table of Contents
  19. :depth: 2
  20. :local:
  21. Installation
  22. ------------
  23. To install pg8000 using `pip` type:
  24. `pip install pg8000`
  25. Native API Interactive Examples
  26. -------------------------------
  27. pg8000 comes with two APIs, the native pg8000 API and the DB-API 2.0 standard
  28. API. These are the examples for the native API, and the DB-API 2.0 examples
  29. follow in the next section.
  30. Basic Example
  31. `````````````
  32. Import pg8000, connect to the database, create a table, add some rows and then
  33. query the table:
  34. >>> import pg8000.native
  35. >>>
  36. >>> # Connect to the database with user name postgres
  37. >>>
  38. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  39. >>>
  40. >>> # Create a temporary table
  41. >>>
  42. >>> con.run("CREATE TEMPORARY TABLE book (id SERIAL, title TEXT)")
  43. >>>
  44. >>> # Populate the table
  45. >>>
  46. >>> for title in ("Ender's Game", "The Magus"):
  47. ... con.run("INSERT INTO book (title) VALUES (:title)", title=title)
  48. >>>
  49. >>> # Print all the rows in the table
  50. >>>
  51. >>> for row in con.run("SELECT * FROM book"):
  52. ... print(row)
  53. [1, "Ender's Game"]
  54. [2, 'The Magus']
  55. >>>
  56. >>> con.close()
  57. Transactions
  58. ````````````
  59. Here's how to run groups of SQL statements in a
  60. `transaction <https://www.postgresql.org/docs/current/tutorial-transactions.html>`_:
  61. >>> import pg8000.native
  62. >>>
  63. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  64. >>>
  65. >>> con.run("START TRANSACTION")
  66. >>>
  67. >>> # Create a temporary table
  68. >>> con.run("CREATE TEMPORARY TABLE book (id SERIAL, title TEXT)")
  69. >>>
  70. >>> for title in ("Ender's Game", "The Magus", "Phineas Finn"):
  71. ... con.run("INSERT INTO book (title) VALUES (:title)", title=title)
  72. >>> con.run("COMMIT")
  73. >>> for row in con.run("SELECT * FROM book"):
  74. ... print(row)
  75. [1, "Ender's Game"]
  76. [2, 'The Magus']
  77. [3, 'Phineas Finn']
  78. >>>
  79. >>> con.close()
  80. rolling back a transaction:
  81. >>> import pg8000.native
  82. >>>
  83. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  84. >>>
  85. >>> # Create a temporary table
  86. >>> con.run("CREATE TEMPORARY TABLE book (id SERIAL, title TEXT)")
  87. >>>
  88. >>> for title in ("Ender's Game", "The Magus", "Phineas Finn"):
  89. ... con.run("INSERT INTO book (title) VALUES (:title)", title=title)
  90. >>>
  91. >>> con.run("START TRANSACTION")
  92. >>> con.run("DELETE FROM book WHERE title = :title", title="Phineas Finn")
  93. >>> con.run("ROLLBACK")
  94. >>> for row in con.run("SELECT * FROM book"):
  95. ... print(row)
  96. [1, "Ender's Game"]
  97. [2, 'The Magus']
  98. [3, 'Phineas Finn']
  99. >>>
  100. >>> con.close()
  101. NB. There is `a longstanding bug <https://github.com/tlocke/pg8000/issues/36>`_
  102. in the PostgreSQL server whereby if a `COMMIT` is issued against a failed
  103. transaction, the transaction is silently rolled back, rather than an error being
  104. returned. pg8000 attempts to detect when this has happened and raise an
  105. `InterfaceError`.
  106. Query Using Functions
  107. `````````````````````
  108. Another query, using some PostgreSQL functions:
  109. >>> import pg8000.native
  110. >>>
  111. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  112. >>>
  113. >>> con.run("SELECT TO_CHAR(TIMESTAMP '2021-10-10', 'YYYY BC')")
  114. [['2021 AD']]
  115. >>>
  116. >>> con.close()
  117. Interval Type
  118. `````````````
  119. A query that returns the PostgreSQL interval type:
  120. >>> import pg8000.native
  121. >>>
  122. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  123. >>>
  124. >>> import datetime
  125. >>>
  126. >>> ts = datetime.date(1980, 4, 27)
  127. >>> con.run("SELECT timestamp '2013-12-01 16:06' - :ts", ts=ts)
  128. [[datetime.timedelta(days=12271, seconds=57960)]]
  129. >>>
  130. >>> con.close()
  131. Point Type
  132. ``````````
  133. A round-trip with a
  134. `PostgreSQL point <https://www.postgresql.org/docs/current/datatype-geometric.html>`_
  135. type:
  136. >>> import pg8000.native
  137. >>>
  138. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  139. >>>
  140. >>> con.run("SELECT CAST(:pt as point)", pt=(2.3,1))
  141. [[(2.3, 1.0)]]
  142. >>>
  143. >>> con.close()
  144. Client Encoding
  145. ```````````````
  146. When communicating with the server, pg8000 uses the character set that the server asks
  147. it to use (the client encoding). By default the client encoding is the database's
  148. character set (chosen when the database is created), but the client encoding can be
  149. changed in a number of ways (eg. setting ``CLIENT_ENCODING`` in ``postgresql.conf``).
  150. Another way of changing the client encoding is by using an SQL command. For example:
  151. >>> import pg8000.native
  152. >>>
  153. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  154. >>>
  155. >>> con.run("SET CLIENT_ENCODING TO 'UTF8'")
  156. >>> con.run("SHOW CLIENT_ENCODING")
  157. [['UTF8']]
  158. >>>
  159. >>> con.close()
  160. JSON
  161. ````
  162. `JSON <https://www.postgresql.org/docs/current/datatype-json.html>`_ always comes back
  163. from the server de-serialized. If the JSON you want to send is a ``dict`` then you can
  164. just do:
  165. >>> import pg8000.native
  166. >>>
  167. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  168. >>>
  169. >>> val = {'name': 'Apollo 11 Cave', 'zebra': True, 'age': 26.003}
  170. >>> con.run("SELECT CAST(:apollo as jsonb)", apollo=val)
  171. [[{'age': 26.003, 'name': 'Apollo 11 Cave', 'zebra': True}]]
  172. >>>
  173. >>> con.close()
  174. JSON can always be sent in serialized form to the server:
  175. >>> import json
  176. >>> import pg8000.native
  177. >>>
  178. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  179. >>>
  180. >>>
  181. >>> val = ['Apollo 11 Cave', True, 26.003]
  182. >>> con.run("SELECT CAST(:apollo as jsonb)", apollo=json.dumps(val))
  183. [[['Apollo 11 Cave', True, 26.003]]]
  184. >>>
  185. >>> con.close()
  186. JSON queries can be have parameters:
  187. >>> import pg8000.native
  188. >>>
  189. >>> with pg8000.native.Connection("postgres", password="cpsnow") as con:
  190. ... con.run(""" SELECT CAST('{"a":1, "b":2}' AS jsonb) @> :v """, v={"b": 2})
  191. [[True]]
  192. Retrieve Column Metadata From Results
  193. `````````````````````````````````````
  194. Find the column metadata returned from a query:
  195. >>> import pg8000.native
  196. >>>
  197. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  198. >>>
  199. >>> con.run("create temporary table quark (id serial, name text)")
  200. >>> for name in ('Up', 'Down'):
  201. ... con.run("INSERT INTO quark (name) VALUES (:name)", name=name)
  202. >>> # Now execute the query
  203. >>>
  204. >>> con.run("SELECT * FROM quark")
  205. [[1, 'Up'], [2, 'Down']]
  206. >>>
  207. >>> # and retrieve the metadata
  208. >>>
  209. >>> con.columns
  210. [{'table_oid': ..., 'column_attrnum': 1, 'type_oid': 23, 'type_size': 4, 'type_modifier': -1, 'format': 0, 'name': 'id'}, {'table_oid': ..., 'column_attrnum': 2, 'type_oid': 25, 'type_size': -1, 'type_modifier': -1, 'format': 0, 'name': 'name'}]
  211. >>>
  212. >>> # Show just the column names
  213. >>>
  214. >>> [c['name'] for c in con.columns]
  215. ['id', 'name']
  216. >>>
  217. >>> con.close()
  218. Notices And Notifications
  219. `````````````````````````
  220. PostgreSQL `notices
  221. <https://www.postgresql.org/docs/current/static/plpgsql-errors-and-messages.html>`_ are
  222. stored in a deque called ``Connection.notices`` and added using the ``append()``
  223. method. Similarly there are ``Connection.notifications`` for `notifications
  224. <https://www.postgresql.org/docs/current/static/sql-notify.html>`_. Here's an example:
  225. >>> import pg8000.native
  226. >>>
  227. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  228. >>>
  229. >>> con.run("LISTEN aliens_landed")
  230. >>> con.run("NOTIFY aliens_landed")
  231. >>> # A notification is a tuple containing (backend_pid, channel, payload)
  232. >>>
  233. >>> con.notifications[0]
  234. (..., 'aliens_landed', '')
  235. >>>
  236. >>> con.close()
  237. Parameter Statuses
  238. ``````````````````
  239. `Certain parameter values are reported by the server automatically at connection startup or whenever
  240. their values change
  241. <https://www.postgresql.org/docs/current/libpq-status.html#LIBPQ-PQPARAMETERSTATUS>`_ and pg8000
  242. stores the latest values in a dict called ``Connection.parameter_statuses``. Here's an example where
  243. we set the ``aplication_name`` parameter and then read it from the ``parameter_statuses``:
  244. >>> import pg8000.native
  245. >>>
  246. >>> con = pg8000.native.Connection(
  247. ... "postgres", password="cpsnow", application_name='AGI')
  248. >>>
  249. >>> con.parameter_statuses['application_name']
  250. 'AGI'
  251. >>>
  252. >>> con.close()
  253. LIMIT ALL
  254. `````````
  255. You might think that the following would work, but in fact it fails:
  256. >>> import pg8000.native
  257. >>>
  258. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  259. >>>
  260. >>> con.run("SELECT 'silo 1' LIMIT :lim", lim='ALL')
  261. Traceback (most recent call last):
  262. pg8000.exceptions.DatabaseError: ...
  263. >>>
  264. >>> con.close()
  265. Instead the `docs say <https://www.postgresql.org/docs/current/sql-select.html>`_ that
  266. you can send ``null`` as an alternative to ``ALL``, which does work:
  267. >>> import pg8000.native
  268. >>>
  269. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  270. >>>
  271. >>> con.run("SELECT 'silo 1' LIMIT :lim", lim=None)
  272. [['silo 1']]
  273. >>>
  274. >>> con.close()
  275. IN and NOT IN
  276. `````````````
  277. You might think that the following would work, but in fact the server doesn't like it:
  278. >>> import pg8000.native
  279. >>>
  280. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  281. >>>
  282. >>> con.run("SELECT 'silo 1' WHERE 'a' IN :v", v=['a', 'b'])
  283. Traceback (most recent call last):
  284. pg8000.exceptions.DatabaseError: ...
  285. >>>
  286. >>> con.close()
  287. instead you can write it using the `unnest
  288. <https://www.postgresql.org/docs/current/functions-array.html>`_ function:
  289. >>> import pg8000.native
  290. >>>
  291. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  292. >>>
  293. >>> con.run(
  294. ... "SELECT 'silo 1' WHERE 'a' IN (SELECT unnest(CAST(:v as varchar[])))",
  295. ... v=['a', 'b'])
  296. [['silo 1']]
  297. >>> con.close()
  298. and you can do the same for ``NOT IN``.
  299. Many SQL Statements Can't Be Parameterized
  300. ``````````````````````````````````````````
  301. In PostgreSQL parameters can only be used for `data values, not identifiers
  302. <https://www.postgresql.org/docs/current/xfunc-sql.html#XFUNC-SQL-FUNCTION-ARGUMENTS>`_.
  303. Sometimes this might not work as expected, for example the following fails:
  304. >>> import pg8000.native
  305. >>>
  306. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  307. >>>
  308. >>> channel = 'top_secret'
  309. >>>
  310. >>> con.run("LISTEN :channel", channel=channel)
  311. Traceback (most recent call last):
  312. pg8000.exceptions.DatabaseError: ...
  313. >>>
  314. >>> con.close()
  315. It fails because the PostgreSQL server doesn't allow this statement to have any
  316. parameters. There are many SQL statements that one might think would have parameters,
  317. but don't. For these cases the SQL has to be created manually, being careful to use the
  318. ``identifier()`` and ``literal()`` functions to escape the values to avoid `SQL
  319. injection attacks <https://en.wikipedia.org/wiki/SQL_injection>`_:
  320. >>> from pg8000.native import Connection, identifier, literal
  321. >>>
  322. >>> con = Connection("postgres", password="cpsnow")
  323. >>>
  324. >>> channel = 'top_secret'
  325. >>> payload = 'Aliens Landed!'
  326. >>> con.run(f"LISTEN {identifier(channel)}")
  327. >>> con.run(f"NOTIFY {identifier(channel)}, {literal(payload)}")
  328. >>>
  329. >>> con.notifications[0]
  330. (..., 'top_secret', 'Aliens Landed!')
  331. >>>
  332. >>> con.close()
  333. COPY FROM And TO A Stream
  334. `````````````````````````
  335. The SQL `COPY <https://www.postgresql.org/docs/current/sql-copy.html>`_ statement can be
  336. used to copy from and to a file or file-like object. Here' an example using the CSV
  337. format:
  338. >>> import pg8000.native
  339. >>> from io import StringIO
  340. >>> import csv
  341. >>>
  342. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  343. >>>
  344. >>> # Create a CSV file in memory
  345. >>>
  346. >>> stream_in = StringIO()
  347. >>> csv_writer = csv.writer(stream_in)
  348. >>> csv_writer.writerow([1, "electron"])
  349. 12
  350. >>> csv_writer.writerow([2, "muon"])
  351. 8
  352. >>> csv_writer.writerow([3, "tau"])
  353. 7
  354. >>> stream_in.seek(0)
  355. 0
  356. >>>
  357. >>> # Create a table and then copy the CSV into it
  358. >>>
  359. >>> con.run("CREATE TEMPORARY TABLE lepton (id SERIAL, name TEXT)")
  360. >>> con.run("COPY lepton FROM STDIN WITH (FORMAT CSV)", stream=stream_in)
  361. >>>
  362. >>> # COPY from a table to a stream
  363. >>>
  364. >>> stream_out = StringIO()
  365. >>> con.run("COPY lepton TO STDOUT WITH (FORMAT CSV)", stream=stream_out)
  366. >>> stream_out.seek(0)
  367. 0
  368. >>> for row in csv.reader(stream_out):
  369. ... print(row)
  370. ['1', 'electron']
  371. ['2', 'muon']
  372. ['3', 'tau']
  373. >>>
  374. >>> con.close()
  375. It's also possible to COPY FROM an iterable, which is useful if you're creating rows
  376. programmatically:
  377. >>> import pg8000.native
  378. >>>
  379. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  380. >>>
  381. >>> # Generator function for creating rows
  382. >>> def row_gen():
  383. ... for i, name in ((1, "electron"), (2, "muon"), (3, "tau")):
  384. ... yield f"{i},{name}\n"
  385. >>>
  386. >>> # Create a table and then copy the CSV into it
  387. >>>
  388. >>> con.run("CREATE TEMPORARY TABLE lepton (id SERIAL, name TEXT)")
  389. >>> con.run("COPY lepton FROM STDIN WITH (FORMAT CSV)", stream=row_gen())
  390. >>>
  391. >>> # COPY from a table to a stream
  392. >>>
  393. >>> stream_out = StringIO()
  394. >>> con.run("COPY lepton TO STDOUT WITH (FORMAT CSV)", stream=stream_out)
  395. >>> stream_out.seek(0)
  396. 0
  397. >>> for row in csv.reader(stream_out):
  398. ... print(row)
  399. ['1', 'electron']
  400. ['2', 'muon']
  401. ['3', 'tau']
  402. >>>
  403. >>> con.close()
  404. Execute Multiple SQL Statements
  405. ```````````````````````````````
  406. If you want to execute a series of SQL statements (eg. an ``.sql`` file), you can run
  407. them as expected:
  408. >>> import pg8000.native
  409. >>>
  410. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  411. >>>
  412. >>> statements = "SELECT 5; SELECT 'Erich Fromm';"
  413. >>>
  414. >>> con.run(statements)
  415. [[5], ['Erich Fromm']]
  416. >>>
  417. >>> con.close()
  418. The only caveat is that when executing multiple statements you can't have any
  419. parameters.
  420. Quoted Identifiers in SQL
  421. `````````````````````````
  422. Say you had a column called ``My Column``. Since it's case sensitive and contains a
  423. space, you'd have to `surround it by double quotes
  424. <https://www.postgresql.org/docs/current/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIER>`_.
  425. But you can't do:
  426. >>> import pg8000.native
  427. >>>
  428. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  429. >>>
  430. >>> con.run("select 'hello' as "My Column"")
  431. Traceback (most recent call last):
  432. SyntaxError: invalid syntax...
  433. >>>
  434. >>> con.close()
  435. since Python uses double quotes to delimit string literals, so one solution is
  436. to use Python's `triple quotes
  437. <https://docs.python.org/3/tutorial/introduction.html#strings>`_ to delimit the string
  438. instead:
  439. >>> import pg8000.native
  440. >>>
  441. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  442. >>>
  443. >>> con.run('''SELECT 'hello' AS "My Column"''')
  444. [['hello']]
  445. >>>
  446. >>> con.close()
  447. another solution, that's especially useful if the identifier comes from an untrusted
  448. source, is to use the ``identifier()`` function, which correctly quotes and escapes the
  449. identifier as needed:
  450. >>> from pg8000.native import Connection, identifier
  451. >>>
  452. >>> con = Connection("postgres", password="cpsnow")
  453. >>>
  454. >>> sql = f"SELECT 'hello' as {identifier('My Column')}"
  455. >>> print(sql)
  456. SELECT 'hello' as "My Column"
  457. >>>
  458. >>> con.run(sql)
  459. [['hello']]
  460. >>>
  461. >>> con.close()
  462. this approach guards against `SQL injection attacks
  463. <https://en.wikipedia.org/wiki/SQL_injection>`_. One thing to note if you're using
  464. explicit schemas (eg. ``pg_catalog.pg_language``) is that the schema name and table name
  465. are both separate identifiers. So to escape them you'd do:
  466. >>> from pg8000.native import Connection, identifier
  467. >>>
  468. >>> con = Connection("postgres", password="cpsnow")
  469. >>>
  470. >>> query = (
  471. ... f"SELECT lanname FROM {identifier('pg_catalog')}.{identifier('pg_language')} "
  472. ... f"WHERE lanname = 'sql'"
  473. ... )
  474. >>> print(query)
  475. SELECT lanname FROM pg_catalog.pg_language WHERE lanname = 'sql'
  476. >>>
  477. >>> con.run(query)
  478. [['sql']]
  479. >>>
  480. >>> con.close()
  481. Custom adapter from a Python type to a PostgreSQL type
  482. ``````````````````````````````````````````````````````
  483. pg8000 has a mapping from Python types to PostgreSQL types for when it needs to send
  484. SQL parameters to the server. The default mapping that comes with pg8000 is designed to
  485. work well in most cases, but you might want to add or replace the default mapping.
  486. A Python ``datetime.timedelta`` object is sent to the server as a PostgreSQL
  487. ``interval`` type, which has the ``oid`` 1186. But let's say we wanted to create our
  488. own Python class to be sent as an ``interval`` type. Then we'd have to register an
  489. adapter:
  490. >>> import pg8000.native
  491. >>>
  492. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  493. >>>
  494. >>> class MyInterval(str):
  495. ... pass
  496. >>>
  497. >>> def my_interval_out(my_interval):
  498. ... return my_interval # Must return a str
  499. >>>
  500. >>> con.register_out_adapter(MyInterval, my_interval_out)
  501. >>> con.run("SELECT CAST(:interval as interval)", interval=MyInterval("2 hours"))
  502. [[datetime.timedelta(seconds=7200)]]
  503. >>>
  504. >>> con.close()
  505. Note that it still came back as a ``datetime.timedelta`` object because we only changed
  506. the mapping from Python to PostgreSQL. See below for an example of how to change the
  507. mapping from PostgreSQL to Python.
  508. Custom adapter from a PostgreSQL type to a Python type
  509. ``````````````````````````````````````````````````````
  510. pg8000 has a mapping from PostgreSQL types to Python types for when it receives SQL
  511. results from the server. The default mapping that comes with pg8000 is designed to work
  512. well in most cases, but you might want to add or replace the default mapping.
  513. If pg8000 receives PostgreSQL ``interval`` type, which has the ``oid`` 1186, it converts
  514. it into a Python ``datetime.timedelta`` object. But let's say we wanted to create our
  515. own Python class to be used instead of ``datetime.timedelta``. Then we'd have to
  516. register an adapter:
  517. >>> import pg8000.native
  518. >>>
  519. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  520. >>>
  521. >>> class MyInterval(str):
  522. ... pass
  523. >>>
  524. >>> def my_interval_in(my_interval_str): # The parameter is of type str
  525. ... return MyInterval(my_interval)
  526. >>>
  527. >>> con.register_in_adapter(1186, my_interval_in)
  528. >>> con.run("SELECT \'2 years'")
  529. [['2 years']]
  530. >>>
  531. >>> con.close()
  532. Note that registering the 'in' adapter only afects the mapping from the PostgreSQL type
  533. to the Python type. See above for an example of how to change the mapping from
  534. PostgreSQL to Python.
  535. Could Not Determine Data Type Of Parameter
  536. ``````````````````````````````````````````
  537. Sometimes you'll get the 'could not determine data type of parameter' error message from
  538. the server:
  539. >>> import pg8000.native
  540. >>>
  541. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  542. >>>
  543. >>> con.run("SELECT :v IS NULL", v=None)
  544. Traceback (most recent call last):
  545. pg8000.exceptions.DatabaseError: {'S': 'ERROR', 'V': 'ERROR', 'C': '42P18', 'M': 'could not determine data type of parameter $1', 'F': 'postgres.c', 'L': '...', 'R': '...'}
  546. >>>
  547. >>> con.close()
  548. One way of solving it is to put a ``CAST`` in the SQL:
  549. >>> import pg8000.native
  550. >>>
  551. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  552. >>>
  553. >>> con.run("SELECT cast(:v as TIMESTAMP) IS NULL", v=None)
  554. [[True]]
  555. >>>
  556. >>> con.close()
  557. Another way is to override the type that pg8000 sends along with each parameter:
  558. >>> import pg8000.native
  559. >>>
  560. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  561. >>>
  562. >>> con.run("SELECT :v IS NULL", v=None, types={'v': pg8000.native.TIMESTAMP})
  563. [[True]]
  564. >>>
  565. >>> con.close()
  566. Prepared Statements
  567. ```````````````````
  568. `Prepared statements <https://www.postgresql.org/docs/current/sql-prepare.html>`_
  569. can be useful in improving performance when you have a statement that's executed
  570. repeatedly. Here's an example:
  571. >>> import pg8000.native
  572. >>>
  573. >>> con = pg8000.native.Connection("postgres", password="cpsnow")
  574. >>>
  575. >>> # Create the prepared statement
  576. >>> ps = con.prepare("SELECT cast(:v as varchar)")
  577. >>>
  578. >>> # Execute the statement repeatedly
  579. >>> ps.run(v="speedy")
  580. [['speedy']]
  581. >>> ps.run(v="rapid")
  582. [['rapid']]
  583. >>> ps.run(v="swift")
  584. [['swift']]
  585. >>>
  586. >>> # Close the prepared statement, releasing resources on the server
  587. >>> ps.close()
  588. >>>
  589. >>> con.close()
  590. Use Environment Variables As Connection Defaults
  591. ````````````````````````````````````````````````
  592. You might want to use the current user as the database username for example:
  593. >>> import pg8000.native
  594. >>> import getpass
  595. >>>
  596. >>> # Connect to the database with current user name
  597. >>> username = getpass.getuser()
  598. >>> connection = pg8000.native.Connection(username, password="cpsnow")
  599. >>>
  600. >>> connection.run("SELECT 'pilau'")
  601. [['pilau']]
  602. >>>
  603. >>> connection.close()
  604. or perhaps you may want to use some of the same `environment variables that libpg uses
  605. <https://www.postgresql.org/docs/current/libpq-envars.html>`_:
  606. >>> import pg8000.native
  607. >>> from os import environ
  608. >>>
  609. >>> username = environ.get('PGUSER', 'postgres')
  610. >>> password = environ.get('PGPASSWORD', 'cpsnow')
  611. >>> host = environ.get('PGHOST', 'localhost')
  612. >>> port = environ.get('PGPORT', '5432')
  613. >>> database = environ.get('PGDATABASE')
  614. >>>
  615. >>> connection = pg8000.native.Connection(
  616. ... username, password=password, host=host, port=port, database=database)
  617. >>>
  618. >>> connection.run("SELECT 'Mr Cairo'")
  619. [['Mr Cairo']]
  620. >>>
  621. >>> connection.close()
  622. It might be asked, why doesn't pg8000 have this behaviour built in? The thinking
  623. follows the second aphorism of `The Zen of Python
  624. <https://www.python.org/dev/peps/pep-0020/>`_:
  625. Explicit is better than implicit.
  626. So we've taken the approach of only being able to set connection parameters using the
  627. ``pg8000.native.Connection()`` constructor.
  628. Connect To PostgreSQL Over SSL
  629. ``````````````````````````````
  630. To connect to the server using SSL defaults do::
  631. import pg8000.native
  632. connection = pg8000.native.Connection('postgres', password="cpsnow", ssl_context=True)
  633. connection.run("SELECT 'The game is afoot!'")
  634. To connect over SSL with custom settings, set the ``ssl_context`` parameter to an
  635. |ssl.SSLContext|_ object:
  636. ::
  637. import pg8000.native
  638. import ssl
  639. ssl_context = ssl.create_default_context()
  640. ssl_context.verify_mode = ssl.CERT_REQUIRED
  641. ssl_context.load_verify_locations('root.pem')
  642. connection = pg8000.native.Connection(
  643. 'postgres', password="cpsnow", ssl_context=ssl_context)
  644. It may be that your PostgreSQL server is behind an SSL proxy server in which case you
  645. can set a pg8000-specific attribute ``ssl.SSLContext.request_ssl = False`` which tells
  646. pg8000 to connect using an SSL socket, but not to request SSL from the PostgreSQL
  647. server:
  648. ::
  649. import pg8000.native
  650. import ssl
  651. ssl_context = ssl.create_default_context()
  652. ssl_context.request_ssl = False
  653. connection = pg8000.native.Connection(
  654. 'postgres', password="cpsnow", ssl_context=ssl_context)
  655. Server-Side Cursors
  656. ```````````````````
  657. You can use the SQL commands `DECLARE
  658. <https://www.postgresql.org/docs/current/sql-declare.html>`_,
  659. `FETCH <https://www.postgresql.org/docs/current/sql-fetch.html>`_,
  660. `MOVE <https://www.postgresql.org/docs/current/sql-move.html>`_ and
  661. `CLOSE <https://www.postgresql.org/docs/current/sql-close.html>`_ to manipulate
  662. server-side cursors. For example:
  663. >>> import pg8000.native
  664. >>>
  665. >>> con = pg8000.native.Connection('postgres', password="cpsnow")
  666. >>> con.run("START TRANSACTION")
  667. >>> con.run("DECLARE c SCROLL CURSOR FOR SELECT * FROM generate_series(1, 100)")
  668. >>> con.run("FETCH FORWARD 5 FROM c")
  669. [[1], [2], [3], [4], [5]]
  670. >>> con.run("MOVE FORWARD 50 FROM c")
  671. >>> con.run("FETCH BACKWARD 10 FROM c")
  672. [[54], [53], [52], [51], [50], [49], [48], [47], [46], [45]]
  673. >>> con.run("CLOSE c")
  674. >>> con.run("ROLLBACK")
  675. >>>
  676. >>> con.close()
  677. BLOBs (Binary Large Objects)
  678. ````````````````````````````
  679. There's a set of `SQL functions
  680. <https://www.postgresql.org/docs/current/lo-funcs.html>`_ for manipulating BLOBs.
  681. Here's an example:
  682. >>> import pg8000.native
  683. >>>
  684. >>> con = pg8000.native.Connection('postgres', password="cpsnow")
  685. >>>
  686. >>> # Create a BLOB and get its oid
  687. >>> data = b'hello'
  688. >>> res = con.run("SELECT lo_from_bytea(0, :data)", data=data)
  689. >>> oid = res[0][0]
  690. >>>
  691. >>> # Create a table and store the oid of the BLOB
  692. >>> con.run("CREATE TEMPORARY TABLE image (raster oid)")
  693. >>>
  694. >>> con.run("INSERT INTO image (raster) VALUES (:oid)", oid=oid)
  695. >>> # Retrieve the data using the oid
  696. >>> con.run("SELECT lo_get(:oid)", oid=oid)
  697. [[b'hello']]
  698. >>>
  699. >>> # Add some data to the end of the BLOB
  700. >>> more_data = b' all'
  701. >>> offset = len(data)
  702. >>> con.run(
  703. ... "SELECT lo_put(:oid, :offset, :data)",
  704. ... oid=oid, offset=offset, data=more_data)
  705. [['']]
  706. >>> con.run("SELECT lo_get(:oid)", oid=oid)
  707. [[b'hello all']]
  708. >>>
  709. >>> # Download a part of the data
  710. >>> con.run("SELECT lo_get(:oid, 6, 3)", oid=oid)
  711. [[b'all']]
  712. >>>
  713. >>> con.close()
  714. Replication Protocol
  715. ````````````````````
  716. The PostgreSQL `Replication Protocol
  717. <https://www.postgresql.org/docs/current/protocol-replication.html>`_ is supported using
  718. the ``replication`` keyword when creating a connection:
  719. >>> import pg8000.native
  720. >>>
  721. >>> con = pg8000.native.Connection(
  722. ... 'postgres', password="cpsnow", replication="database")
  723. >>>
  724. >>> con.run("IDENTIFY_SYSTEM")
  725. [['...', 1, '.../...', 'postgres']]
  726. >>>
  727. >>> con.close()
  728. DB-API 2 Interactive Examples
  729. -----------------------------
  730. These examples stick to the DB-API 2.0 standard.
  731. Basic Example
  732. `````````````
  733. Import pg8000, connect to the database, create a table, add some rows and then query the
  734. table:
  735. >>> import pg8000.dbapi
  736. >>>
  737. >>> conn = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  738. >>> cursor = conn.cursor()
  739. >>> cursor.execute("CREATE TEMPORARY TABLE book (id SERIAL, title TEXT)")
  740. >>> cursor.execute(
  741. ... "INSERT INTO book (title) VALUES (%s), (%s) RETURNING id, title",
  742. ... ("Ender's Game", "Speaker for the Dead"))
  743. >>> results = cursor.fetchall()
  744. >>> for row in results:
  745. ... id, title = row
  746. ... print("id = %s, title = %s" % (id, title))
  747. id = 1, title = Ender's Game
  748. id = 2, title = Speaker for the Dead
  749. >>> conn.commit()
  750. >>>
  751. >>> conn.close()
  752. Query Using Functions
  753. `````````````````````
  754. Another query, using some PostgreSQL functions:
  755. >>> import pg8000.dbapi
  756. >>>
  757. >>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  758. >>> cursor = con.cursor()
  759. >>>
  760. >>> cursor.execute("SELECT TO_CHAR(TIMESTAMP '2021-10-10', 'YYYY BC')")
  761. >>> cursor.fetchone()
  762. ['2021 AD']
  763. >>>
  764. >>> con.close()
  765. Interval Type
  766. `````````````
  767. A query that returns the PostgreSQL interval type:
  768. >>> import datetime
  769. >>> import pg8000.dbapi
  770. >>>
  771. >>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  772. >>> cursor = con.cursor()
  773. >>>
  774. >>> cursor.execute("SELECT timestamp '2013-12-01 16:06' - %s",
  775. ... (datetime.date(1980, 4, 27),))
  776. >>> cursor.fetchone()
  777. [datetime.timedelta(days=12271, seconds=57960)]
  778. >>>
  779. >>> con.close()
  780. Point Type
  781. ``````````
  782. A round-trip with a `PostgreSQL point
  783. <https://www.postgresql.org/docs/current/datatype-geometric.html>`_ type:
  784. >>> import pg8000.dbapi
  785. >>>
  786. >>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  787. >>> cursor = con.cursor()
  788. >>>
  789. >>> cursor.execute("SELECT cast(%s as point)", ((2.3,1),))
  790. >>> cursor.fetchone()
  791. [(2.3, 1.0)]
  792. >>>
  793. >>> con.close()
  794. Numeric Parameter Style
  795. ```````````````````````
  796. pg8000 supports all the DB-API parameter styles. Here's an example of using the
  797. 'numeric' parameter style:
  798. >>> import pg8000.dbapi
  799. >>>
  800. >>> pg8000.dbapi.paramstyle = "numeric"
  801. >>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  802. >>> cursor = con.cursor()
  803. >>>
  804. >>> cursor.execute("SELECT array_prepend(:1, CAST(:2 AS int[]))", (500, [1, 2, 3, 4],))
  805. >>> cursor.fetchone()
  806. [[500, 1, 2, 3, 4]]
  807. >>> pg8000.dbapi.paramstyle = "format"
  808. >>>
  809. >>> con.close()
  810. Autocommit
  811. ``````````
  812. Following the DB-API specification, autocommit is off by default. It can be turned on by
  813. using the autocommit property of the connection:
  814. >>> import pg8000.dbapi
  815. >>>
  816. >>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  817. >>> con.autocommit = True
  818. >>>
  819. >>> cur = con.cursor()
  820. >>> cur.execute("vacuum")
  821. >>> conn.autocommit = False
  822. >>> cur.close()
  823. >>>
  824. >>> con.close()
  825. Client Encoding
  826. ```````````````
  827. When communicating with the server, pg8000 uses the character set that the server asks
  828. it to use (the client encoding). By default the client encoding is the database's
  829. character set (chosen when the database is created), but the client encoding can be
  830. changed in a number of ways (eg. setting ``CLIENT_ENCODING`` in ``postgresql.conf``).
  831. Another way of changing the client encoding is by using an SQL command. For example:
  832. >>> import pg8000.dbapi
  833. >>>
  834. >>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  835. >>> cur = con.cursor()
  836. >>> cur.execute("SET CLIENT_ENCODING TO 'UTF8'")
  837. >>> cur.execute("SHOW CLIENT_ENCODING")
  838. >>> cur.fetchone()
  839. ['UTF8']
  840. >>> cur.close()
  841. >>>
  842. >>> con.close()
  843. JSON
  844. ````
  845. JSON is sent to the server serialized, and returned de-serialized. Here's an example:
  846. >>> import json
  847. >>> import pg8000.dbapi
  848. >>>
  849. >>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  850. >>> cur = con.cursor()
  851. >>> val = ['Apollo 11 Cave', True, 26.003]
  852. >>> cur.execute("SELECT cast(%s as json)", (json.dumps(val),))
  853. >>> cur.fetchone()
  854. [['Apollo 11 Cave', True, 26.003]]
  855. >>> cur.close()
  856. >>>
  857. >>> con.close()
  858. JSON queries can be have parameters:
  859. >>> import pg8000.dbapi
  860. >>>
  861. >>> with pg8000.dbapi.connect("postgres", password="cpsnow") as con:
  862. ... cur = con.cursor()
  863. ... cur.execute(""" SELECT CAST('{"a":1, "b":2}' AS jsonb) @> %s """, ({"b": 2},))
  864. ... for row in cur.fetchall():
  865. ... print(row)
  866. [True]
  867. Retrieve Column Names From Results
  868. ``````````````````````````````````
  869. Use the columns names retrieved from a query:
  870. >>> import pg8000
  871. >>> conn = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  872. >>> c = conn.cursor()
  873. >>> c.execute("create temporary table quark (id serial, name text)")
  874. >>> c.executemany("INSERT INTO quark (name) VALUES (%s)", (("Up",), ("Down",)))
  875. >>> #
  876. >>> # Now retrieve the results
  877. >>> #
  878. >>> c.execute("select * from quark")
  879. >>> rows = c.fetchall()
  880. >>> keys = [k[0] for k in c.description]
  881. >>> results = [dict(zip(keys, row)) for row in rows]
  882. >>> assert results == [{'id': 1, 'name': 'Up'}, {'id': 2, 'name': 'Down'}]
  883. >>>
  884. >>> conn.close()
  885. COPY from and to a file
  886. ```````````````````````
  887. The SQL `COPY <https://www.postgresql.org/docs/current/sql-copy.html>`__ statement can
  888. be used to copy from and to a file or file-like object:
  889. >>> from io import StringIO
  890. >>> import pg8000.dbapi
  891. >>>
  892. >>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  893. >>> cur = con.cursor()
  894. >>> #
  895. >>> # COPY from a stream to a table
  896. >>> #
  897. >>> stream_in = StringIO('1\telectron\n2\tmuon\n3\ttau\n')
  898. >>> cur = con.cursor()
  899. >>> cur.execute("create temporary table lepton (id serial, name text)")
  900. >>> cur.execute("COPY lepton FROM stdin", stream=stream_in)
  901. >>> #
  902. >>> # Now COPY from a table to a stream
  903. >>> #
  904. >>> stream_out = StringIO()
  905. >>> cur.execute("copy lepton to stdout", stream=stream_out)
  906. >>> stream_out.getvalue()
  907. '1\telectron\n2\tmuon\n3\ttau\n'
  908. >>>
  909. >>> con.close()
  910. Server-Side Cursors
  911. ```````````````````
  912. You can use the SQL commands `DECLARE
  913. <https://www.postgresql.org/docs/current/sql-declare.html>`_,
  914. `FETCH <https://www.postgresql.org/docs/current/sql-fetch.html>`_,
  915. `MOVE <https://www.postgresql.org/docs/current/sql-move.html>`_ and
  916. `CLOSE <https://www.postgresql.org/docs/current/sql-close.html>`_ to manipulate
  917. server-side cursors. For example:
  918. >>> import pg8000.dbapi
  919. >>>
  920. >>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  921. >>> cur = con.cursor()
  922. >>> cur.execute("START TRANSACTION")
  923. >>> cur.execute(
  924. ... "DECLARE c SCROLL CURSOR FOR SELECT * FROM generate_series(1, 100)")
  925. >>> cur.execute("FETCH FORWARD 5 FROM c")
  926. >>> cur.fetchall()
  927. ([1], [2], [3], [4], [5])
  928. >>> cur.execute("MOVE FORWARD 50 FROM c")
  929. >>> cur.execute("FETCH BACKWARD 10 FROM c")
  930. >>> cur.fetchall()
  931. ([54], [53], [52], [51], [50], [49], [48], [47], [46], [45])
  932. >>> cur.execute("CLOSE c")
  933. >>> cur.execute("ROLLBACK")
  934. >>>
  935. >>> con.close()
  936. BLOBs (Binary Large Objects)
  937. ````````````````````````````
  938. There's a set of `SQL functions
  939. <https://www.postgresql.org/docs/current/lo-funcs.html>`_ for manipulating BLOBs.
  940. Here's an example:
  941. >>> import pg8000.dbapi
  942. >>>
  943. >>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
  944. >>> cur = con.cursor()
  945. >>>
  946. >>> # Create a BLOB and get its oid
  947. >>> data = b'hello'
  948. >>> cur = con.cursor()
  949. >>> cur.execute("SELECT lo_from_bytea(0, %s)", [data])
  950. >>> oid = cur.fetchone()[0]
  951. >>>
  952. >>> # Create a table and store the oid of the BLOB
  953. >>> cur.execute("CREATE TEMPORARY TABLE image (raster oid)")
  954. >>> cur.execute("INSERT INTO image (raster) VALUES (%s)", [oid])
  955. >>>
  956. >>> # Retrieve the data using the oid
  957. >>> cur.execute("SELECT lo_get(%s)", [oid])
  958. >>> cur.fetchall()
  959. ([b'hello'],)
  960. >>>
  961. >>> # Add some data to the end of the BLOB
  962. >>> more_data = b' all'
  963. >>> offset = len(data)
  964. >>> cur.execute("SELECT lo_put(%s, %s, %s)", [oid, offset, more_data])
  965. >>> cur.execute("SELECT lo_get(%s)", [oid])
  966. >>> cur.fetchall()
  967. ([b'hello all'],)
  968. >>>
  969. >>> # Download a part of the data
  970. >>> cur.execute("SELECT lo_get(%s, 6, 3)", [oid])
  971. >>> cur.fetchall()
  972. ([b'all'],)
  973. >>>
  974. >>> con.close()
  975. Type Mapping
  976. ------------
  977. The following table shows the default mapping between Python types and PostgreSQL types,
  978. and vice versa.
  979. If pg8000 doesn't recognize a type that it receives from PostgreSQL, it will return it
  980. as a ``str`` type. This is how pg8000 handles PostgreSQL ``enum`` and XML types. It's
  981. possible to change the default mapping using adapters (see the examples).
  982. .. table:: Python to PostgreSQL Type Mapping
  983. +-----------------------+-----------------+-----------------------------------------+
  984. | Python Type | PostgreSQL Type | Notes |
  985. +=======================+=================+=========================================+
  986. | bool | bool | |
  987. +-----------------------+-----------------+-----------------------------------------+
  988. | int | int4 | |
  989. +-----------------------+-----------------+-----------------------------------------+
  990. | str | text | |
  991. +-----------------------+-----------------+-----------------------------------------+
  992. | float | float8 | |
  993. +-----------------------+-----------------+-----------------------------------------+
  994. | decimal.Decimal | numeric | |
  995. +-----------------------+-----------------+-----------------------------------------+
  996. | bytes | bytea | |
  997. +-----------------------+-----------------+-----------------------------------------+
  998. | datetime.datetime | timestamp | +/-infinity PostgreSQL values are |
  999. | (without tzinfo) | without | represented as Python ``str`` values. |
  1000. | | timezone | If a ``timestamp`` is too big for |
  1001. | | | ``datetime.datetime`` then a ``str`` is |
  1002. | | | used. |
  1003. +-----------------------+-----------------+-----------------------------------------+
  1004. | datetime.datetime | timestamp with | +/-infinity PostgreSQL values are |
  1005. | (with tzinfo) | timezone | represented as Python ``str`` values. |
  1006. | | | If a ``timestamptz`` is too big for |
  1007. | | | ``datetime.datetime`` then a ``str`` is |
  1008. | | | used. |
  1009. +-----------------------+-----------------+-----------------------------------------+
  1010. | datetime.date | date | +/-infinity PostgreSQL values are |
  1011. | | | represented as Python ``str`` values. |
  1012. | | | If a ``date`` is too big for a |
  1013. | | | ``datetime.date`` then a ``str`` is |
  1014. | | | used. |
  1015. +-----------------------+-----------------+-----------------------------------------+
  1016. | datetime.time | time without | |
  1017. | | time zone | |
  1018. +-----------------------+-----------------+-----------------------------------------+
  1019. | datetime.timedelta | interval | If an ``interval`` is too big for |
  1020. | | | ``datetime.timedelta`` then a |
  1021. | | | ``PGInterval`` is used. |
  1022. +-----------------------+-----------------+-----------------------------------------+
  1023. | None | NULL | |
  1024. +-----------------------+-----------------+-----------------------------------------+
  1025. | uuid.UUID | uuid | |
  1026. +-----------------------+-----------------+-----------------------------------------+
  1027. | ipaddress.IPv4Address | inet | |
  1028. +-----------------------+-----------------+-----------------------------------------+
  1029. | ipaddress.IPv6Address | inet | |
  1030. +-----------------------+-----------------+-----------------------------------------+
  1031. | ipaddress.IPv4Network | inet | |
  1032. +-----------------------+-----------------+-----------------------------------------+
  1033. | ipaddress.IPv6Network | inet | |
  1034. +-----------------------+-----------------+-----------------------------------------+
  1035. | int | xid | |
  1036. +-----------------------+-----------------+-----------------------------------------+
  1037. | list of int | INT4[] | |
  1038. +-----------------------+-----------------+-----------------------------------------+
  1039. | list of float | FLOAT8[] | |
  1040. +-----------------------+-----------------+-----------------------------------------+
  1041. | list of bool | BOOL[] | |
  1042. +-----------------------+-----------------+-----------------------------------------+
  1043. | list of str | TEXT[] | |
  1044. +-----------------------+-----------------+-----------------------------------------+
  1045. | int | int2vector | Only from PostgreSQL to Python |
  1046. +-----------------------+-----------------+-----------------------------------------+
  1047. | JSON | json, jsonb | The Python JSON is provided as a Python |
  1048. | | | serialized string. Results returned as |
  1049. | | | de-serialized JSON. |
  1050. +-----------------------+-----------------+-----------------------------------------+
  1051. | pg8000.Range | \*range | PostgreSQL multirange types are |
  1052. | | | represented in Python as a list of |
  1053. | | | range types. |
  1054. +-----------------------+-----------------+-----------------------------------------+
  1055. | tuple | composite type | Only from Python to PostgreSQL |
  1056. +-----------------------+-----------------+-----------------------------------------+
  1057. Theory Of Operation
  1058. -------------------
  1059. A concept is tolerated inside the microkernel only if moving it outside the kernel,
  1060. i.e., permitting competing implementations, would prevent the implementation of the
  1061. system's required functionality.
  1062. -- Jochen Liedtke, Liedtke's minimality principle
  1063. pg8000 is designed to be used with one thread per connection.
  1064. Pg8000 communicates with the database using the `PostgreSQL Frontend/Backend Protocol
  1065. <https://www.postgresql.org/docs/current/protocol.html>`_ (FEBE). If a query has no
  1066. parameters, pg8000 uses the 'simple query protocol'. If a query does have parameters,
  1067. pg8000 uses the 'extended query protocol' with unnamed prepared statements. The steps
  1068. for a query with parameters are:
  1069. 1. Query comes in.
  1070. #. Send a PARSE message to the server to create an unnamed prepared statement.
  1071. #. Send a BIND message to run against the unnamed prepared statement, resulting in an
  1072. unnamed portal on the server.
  1073. #. Send an EXECUTE message to read all the results from the portal.
  1074. It's also possible to use named prepared statements. In which case the prepared
  1075. statement persists on the server, and represented in pg8000 using a
  1076. ``PreparedStatement`` object. This means that the PARSE step gets executed once up
  1077. front, and then only the BIND and EXECUTE steps are repeated subsequently.
  1078. There are a lot of PostgreSQL data types, but few primitive data types in Python. By
  1079. default, pg8000 doesn't send PostgreSQL data type information in the PARSE step, in
  1080. which case PostgreSQL assumes the types implied by the SQL statement. In some cases
  1081. PostgreSQL can't work out a parameter type and so an `explicit cast
  1082. <https://www.postgresql.org/docs/current/static/sql-expressions.html#SQL-SYNTAX-TYPE-CASTS>`_
  1083. can be used in the SQL.
  1084. In the FEBE protocol, each query parameter can be sent to the server either as binary
  1085. or text according to the format code. In pg8000 the parameters are always sent as text.
  1086. Occasionally, the network connection between pg8000 and the server may go down. If
  1087. pg8000 encounters a network problem it'll raise an ``InterfaceError`` with the message
  1088. ``network error`` and with the original exception set as the `cause
  1089. <https://docs.python.org/3/reference/simple_stmts.html#the-raise-statement>`_.
  1090. Native API Docs
  1091. ---------------
  1092. `Native API Docs <docs/native_api_docs.rst>`_
  1093. DB-API 2 Docs
  1094. -------------
  1095. `DB-API 2 Docs <docs/dbapi2_docs.rst>`_
  1096. Design Decisions
  1097. ----------------
  1098. For the ``Range`` type, the constructor follows the `PostgreSQL range constructor functions <https://www.postgresql.org/docs/current/rangetypes.html#RANGETYPES-CONSTRUCT>`_
  1099. which makes `[closed, open) <https://fhur.me/posts/always-use-closed-open-intervals>`_
  1100. the easiest to express:
  1101. >>> from pg8000.types import Range
  1102. >>>
  1103. >>> pg_range = Range(2, 6)
  1104. Tests
  1105. -----
  1106. - Install `tox <http://testrun.org/tox/latest/>`_: ``pip install tox``
  1107. - Enable the PostgreSQL hstore extension by running the SQL command:
  1108. ``create extension hstore;``
  1109. - Add a line to ``pg_hba.conf`` for the various authentication options:
  1110. ::
  1111. host pg8000_md5 all 127.0.0.1/32 md5
  1112. host pg8000_gss all 127.0.0.1/32 gss
  1113. host pg8000_password all 127.0.0.1/32 password
  1114. host pg8000_scram_sha_256 all 127.0.0.1/32 scram-sha-256
  1115. host all all 127.0.0.1/32 trust
  1116. - Set password encryption to ``scram-sha-256`` in ``postgresql.conf``:
  1117. ``password_encryption = 'scram-sha-256'``
  1118. - Set the password for the postgres user: ``ALTER USER postgresql WITH PASSWORD 'pw';``
  1119. - Run ``tox`` from the ``pg8000`` directory: ``tox``
  1120. This will run the tests against the Python version of the virtual environment, on the
  1121. machine, and the installed PostgreSQL version listening on port 5432, or the ``PGPORT``
  1122. environment variable if set.
  1123. Benchmarks are run as part of the test suite at ``tests/test_benchmarks.py``.
  1124. README.rst
  1125. ----------
  1126. This file is written in the `reStructuredText
  1127. <https://docutils.sourceforge.io/docs/user/rst/quickref.html>`_ format. To generate an
  1128. HTML page from it, do:
  1129. - Activate the virtual environment: ``source venv/bin/activate``
  1130. - Install ``Sphinx``: ``pip install Sphinx``
  1131. - Run ``rst2html.py``: ``rst2html.py README.rst README.html``
  1132. Doing A Release Of pg8000
  1133. -------------------------
  1134. Run ``tox`` to make sure all tests pass, then update the release notes, then do:
  1135. ::
  1136. git tag -a x.y.z -m "version x.y.z"
  1137. rm -r dist
  1138. python -m build
  1139. twine upload dist/*
  1140. Release Notes
  1141. -------------
  1142. `Release Notes <docs/release_notes.rst>`_