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
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
1600
1601
1602
1603
1604
1605
1606
1607
1608
1609
1610
1611
1612
1613
1614
1615
1616
1617
1618
1619
1620
1621
1622
1623
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638
1639
1640
1641
1642
1643
1644
1645
1646
1647
1648
1649
1650
1651
1652
1653
1654
1655
1656
1657
1658
1659
1660
1661
1662
1663
1664
1665
1666
1667
1668
1669
1670
1671
1672
1673
1674
1675
1676
1677
1678
1679
1680
1681
1682
1683
1684
1685
1686
1687
1688
1689
1690
1691
1692
1693
1694
1695
1696
1697
1698
1699
1700
1701
1702
1703
1704
1705
1706
1707
1708
1709
1710
1711
1712
1713
1714
1715
1716
1717
1718
1719
1720
1721
1722
1723
1724
1725
1726
1727
1728
1729
1730
1731
1732
1733
1734
1735
1736
1737
1738
1739
1740
1741
1742
1743
1744
1745
1746
1747
1748
1749
1750
1751
1752
1753
1754
1755
1756
1757
1758
1759
1760
1761
1762
1763
1764
1765
1766
1767
1768
1769
1770
1771
1772
1773
1774
1775
1776
1777
1778
1779
1780
1781
1782
1783
1784
1785
1786
1787
1788
1789
1790
1791
1792
1793
1794
1795
1796
1797
1798
1799
1800
1801
1802
1803
1804
1805
1806
1807
1808
1809
1810
1811
1812
1813
1814
1815
1816
1817
1818
1819
1820
1821
1822
1823
1824
1825
1826
1827
1828
1829
1830
1831
1832
1833
1834
1835
1836
1837
1838
1839
1840
1841
1842
1843
1844
1845
1846
1847
1848
1849
1850
1851
1852
1853
1854
1855
1856
1857
1858
1859
1860
1861
1862
1863
1864
1865
1866
1867
1868
1869
1870
1871
1872
1873
1874
1875
1876
1877
1878
1879
1880
1881
1882
1883
1884
1885
1886
1887
1888
1889
1890
1891
1892
1893
1894
1895
1896
1897
1898
1899
1900
1901
1902
1903
1904
1905
1906
1907
1908
1909
1910
1911
1912
1913
1914
1915
1916
1917
1918
1919
1920
1921
1922
1923
1924
1925
1926
1927
1928
1929
1930
1931
1932
1933
1934
1935
1936
1937
1938
1939
1940
1941
1942
1943
1944
1945
1946
1947
1948
1949
1950
1951
1952
1953
1954
1955
1956
1957
1958
1959
1960
1961
1962
1963
1964
1965
1966
1967
1968
1969
1970
1971
1972
1973
1974
1975
1976
1977
1978
1979
1980
1981
1982
1983
1984
1985
1986
1987
1988
1989
1990
1991
1992
1993
1994
1995
1996
1997
1998
1999
2000
2001
2002
2003
2004
2005
2006
2007
2008
2009
2010
2011
2012
2013
2014
2015
2016
2017
2018
2019
2020
2021
2022
2023
2024
2025
2026
2027
2028
2029
2030
2031
2032
2033
2034
2035
2036
2037
2038
2039
2040
2041
2042
2043
2044
2045
2046
2047
2048
2049
2050
2051
2052
2053
2054
2055
2056
2057
2058
2059
2060
2061
2062
2063
2064
2065
2066
2067
2068
2069
2070
2071
2072
2073
2074
2075
2076
2077
2078
2079
2080
2081
2082
2083
2084
2085
2086
2087
2088
2089
2090
2091
2092
2093
2094
2095
2096
2097
2098
2099
2100
2101
2102
2103
2104
2105
2106
2107
2108
2109
2110
2111
2112
2113
2114
2115
2116
2117
2118
2119
2120
2121
2122
2123
2124
2125
2126
2127
2128
2129
2130
2131
2132
2133
2134
2135
2136
2137
2138
2139
2140
2141
2142
2143
2144
2145
2146
2147
2148
2149
2150
2151
2152
2153
2154
2155
2156
2157
2158
2159
2160
2161
2162
2163
2164
2165
2166
2167
2168
2169
2170
2171
2172
2173
2174
2175
2176
2177
2178
2179
2180
2181
2182
2183
2184
2185
2186
2187
2188
2189
2190
2191
2192
2193
2194
2195
2196
2197
2198
2199
2200
2201
2202
2203
2204
2205
2206
2207
2208
2209
2210
2211
2212
2213
2214
2215
2216
2217
2218
2219
2220
2221
2222
2223
2224
2225
2226
2227
2228
2229
2230
2231
2232
2233
2234
2235
2236
2237
2238
2239
2240
2241
2242
2243
2244
|
# pg8000
pg8000 is a pure-[Python](https://www.python.org/)
[PostgreSQL](http://www.postgresql.org/) driver that complies with
[DB-API 2.0](http://www.python.org/dev/peps/pep-0249/). It is tested on Python versions
3.8+, on CPython and PyPy, and PostgreSQL versions 12+. pg8000's name comes from the
belief that it is probably about the 8000th PostgreSQL interface for Python. pg8000 is
distributed under the BSD 3-clause license.
All bug reports, feature requests and contributions are welcome at
[http://github.com/tlocke/pg8000/](http://github.com/tlocke/pg8000/).
[![Workflow Status Badge](https://github.com/tlocke/pg8000/workflows/pg8000/badge.svg)](https://github.com/tlocke/pg8000/actions)
## Installation
To install pg8000 using `pip` type: `pip install pg8000`
## Native API Interactive Examples
pg8000 comes with two APIs, the native pg8000 API and the DB-API 2.0 standard
API. These are the examples for the native API, and the DB-API 2.0 examples
follow in the next section.
### Basic Example
Import pg8000, connect to the database, create a table, add some rows and then
query the table:
```python
>>> import pg8000.native
>>>
>>> # Connect to the database with user name postgres
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> # Create a temporary table
>>>
>>> con.run("CREATE TEMPORARY TABLE book (id SERIAL, title TEXT)")
>>>
>>> # Populate the table
>>>
>>> for title in ("Ender's Game", "The Magus"):
... con.run("INSERT INTO book (title) VALUES (:title)", title=title)
>>>
>>> # Print all the rows in the table
>>>
>>> for row in con.run("SELECT * FROM book"):
... print(row)
[1, "Ender's Game"]
[2, 'The Magus']
>>>
>>> con.close()
```
### Transactions
Here's how to run groups of SQL statements in a
[transaction](https://www.postgresql.org/docs/current/tutorial-transactions.html>):
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("START TRANSACTION")
>>>
>>> # Create a temporary table
>>> con.run("CREATE TEMPORARY TABLE book (id SERIAL, title TEXT)")
>>>
>>> for title in ("Ender's Game", "The Magus", "Phineas Finn"):
... con.run("INSERT INTO book (title) VALUES (:title)", title=title)
>>> con.run("COMMIT")
>>> for row in con.run("SELECT * FROM book"):
... print(row)
[1, "Ender's Game"]
[2, 'The Magus']
[3, 'Phineas Finn']
>>>
>>> con.close()
```
rolling back a transaction:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> # Create a temporary table
>>> con.run("CREATE TEMPORARY TABLE book (id SERIAL, title TEXT)")
>>>
>>> for title in ("Ender's Game", "The Magus", "Phineas Finn"):
... con.run("INSERT INTO book (title) VALUES (:title)", title=title)
>>>
>>> con.run("START TRANSACTION")
>>> con.run("DELETE FROM book WHERE title = :title", title="Phineas Finn")
>>> con.run("ROLLBACK")
>>> for row in con.run("SELECT * FROM book"):
... print(row)
[1, "Ender's Game"]
[2, 'The Magus']
[3, 'Phineas Finn']
>>>
>>> con.close()
```
NB. There is [a longstanding bug](https://github.com/tlocke/pg8000/issues/36>) in the
PostgreSQL server whereby if a `COMMIT` is issued against a failed transaction, the
transaction is silently rolled back, rather than an error being returned. pg8000
attempts to detect when this has happened and raise an `InterfaceError`.
### Query Using Functions
Another query, using some PostgreSQL functions:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("SELECT TO_CHAR(TIMESTAMP '2021-10-10', 'YYYY BC')")
[['2021 AD']]
>>>
>>> con.close()
```
### Interval Type
A query that returns the PostgreSQL interval type:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> import datetime
>>>
>>> ts = datetime.date(1980, 4, 27)
>>> con.run("SELECT timestamp '2013-12-01 16:06' - :ts", ts=ts)
[[datetime.timedelta(days=12271, seconds=57960)]]
>>>
>>> con.close()
```
### Point Type
A round-trip with a
[PostgreSQL point](https://www.postgresql.org/docs/current/datatype-geometric.html)
type:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("SELECT CAST(:pt as point)", pt=(2.3,1))
[[(2.3, 1.0)]]
>>>
>>> con.close()
```
### Client Encoding
When communicating with the server, pg8000 uses the character set that the server asks
it to use (the client encoding). By default the client encoding is the database's
character set (chosen when the database is created), but the client encoding can be
changed in a number of ways (eg. setting `CLIENT_ENCODING` in `postgresql.conf`).
Another way of changing the client encoding is by using an SQL command. For example:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("SET CLIENT_ENCODING TO 'UTF8'")
>>> con.run("SHOW CLIENT_ENCODING")
[['UTF8']]
>>>
>>> con.close()
```
### JSON
[JSON](https://www.postgresql.org/docs/current/datatype-json.html) always comes back
from the server de-serialized. If the JSON you want to send is a ``dict`` then you can
just do:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> val = {'name': 'Apollo 11 Cave', 'zebra': True, 'age': 26.003}
>>> con.run("SELECT CAST(:apollo as jsonb)", apollo=val)
[[{'age': 26.003, 'name': 'Apollo 11 Cave', 'zebra': True}]]
>>>
>>> con.close()
```
JSON can always be sent in serialized form to the server:
```python
>>> import json
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>>
>>> val = ['Apollo 11 Cave', True, 26.003]
>>> con.run("SELECT CAST(:apollo as jsonb)", apollo=json.dumps(val))
[[['Apollo 11 Cave', True, 26.003]]]
>>>
>>> con.close()
```
JSON queries can be have parameters:
```python
>>> import pg8000.native
>>>
>>> with pg8000.native.Connection("postgres", password="cpsnow") as con:
... con.run(""" SELECT CAST('{"a":1, "b":2}' AS jsonb) @> :v """, v={"b": 2})
[[True]]
```
### Retrieve Column Metadata From Results
Find the column metadata returned from a query:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("create temporary table quark (id serial, name text)")
>>> for name in ('Up', 'Down'):
... con.run("INSERT INTO quark (name) VALUES (:name)", name=name)
>>> # Now execute the query
>>>
>>> con.run("SELECT * FROM quark")
[[1, 'Up'], [2, 'Down']]
>>>
>>> # and retrieve the metadata
>>>
>>> con.columns
[{'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'}]
>>>
>>> # Show just the column names
>>>
>>> [c['name'] for c in con.columns]
['id', 'name']
>>>
>>> con.close()
```
### Notices And Notifications
PostgreSQL [notices
](https://www.postgresql.org/docs/current/static/plpgsql-errors-and-messages.html) are
stored in a deque called `Connection.notices` and added using the `append()` method.
Similarly there are `Connection.notifications` for [notifications
](https://www.postgresql.org/docs/current/static/sql-notify.html). Here's an example:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("LISTEN aliens_landed")
>>> con.run("NOTIFY aliens_landed")
>>> # A notification is a tuple containing (backend_pid, channel, payload)
>>>
>>> con.notifications[0]
(..., 'aliens_landed', '')
>>>
>>> con.close()
```
### Parameter Statuses
[Certain parameter values are reported by the server automatically at connection startup or whenever
their values change
](https://www.postgresql.org/docs/current/libpq-status.html#LIBPQ-PQPARAMETERSTATUS>) and
pg8000 stores the latest values in a dict called `Connection.parameter_statuses`. Here's
an example where we set the `aplication_name` parameter and then read it from the
`parameter_statuses`:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection(
... "postgres", password="cpsnow", application_name='AGI')
>>>
>>> con.parameter_statuses['application_name']
'AGI'
>>>
>>> con.close()
```
### LIMIT ALL
You might think that the following would work, but in fact it fails:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("SELECT 'silo 1' LIMIT :lim", lim='ALL')
Traceback (most recent call last):
pg8000.exceptions.DatabaseError: ...
>>>
>>> con.close()
```
Instead the [docs say](https://www.postgresql.org/docs/current/sql-select.html) that you
can send `null` as an alternative to `ALL`, which does work:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("SELECT 'silo 1' LIMIT :lim", lim=None)
[['silo 1']]
>>>
>>> con.close()
```
### IN and NOT IN
You might think that the following would work, but in fact the server doesn't like it:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("SELECT 'silo 1' WHERE 'a' IN :v", v=['a', 'b'])
Traceback (most recent call last):
pg8000.exceptions.DatabaseError: ...
>>>
>>> con.close()
```
the most straightforward way to get around this problem is to rewrie the query using the [`ANY`](
https://www.postgresql.org/docs/current/functions-comparisons.html#FUNCTIONS-COMPARISONS-ANY-SOME)
function:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("SELECT 'silo 1' WHERE 'a' = ANY(:v)", v=['a', 'b'])
[['silo 1']]
>>> con.close()
```
However, using the array variant of `ANY` [may cause a performance problem](
https://stackoverflow.com/questions/34627026/in-vs-any-operator-in-postgresql/34627688#34627688)
and so you can use the [subquery variant of `IN`](
https://www.postgresql.org/docs/current/functions-subquery.html#FUNCTIONS-SUBQUERY-IN)
with the [unnest
](https://www.postgresql.org/docs/current/functions-array.html) function:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run(
... "SELECT 'silo 1' WHERE 'a' IN (SELECT unnest(CAST(:v as varchar[])))",
... v=['a', 'b'])
[['silo 1']]
>>> con.close()
```
and you can do the same for `NOT IN`.
### Many SQL Statements Can't Be Parameterized
In PostgreSQL parameters can only be used for [data values, not identifiers
](https://www.postgresql.org/docs/current/xfunc-sql.html#XFUNC-SQL-FUNCTION-ARGUMENTS).
Sometimes this might not work as expected, for example the following fails:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> channel = 'top_secret'
>>>
>>> con.run("LISTEN :channel", channel=channel)
Traceback (most recent call last):
pg8000.exceptions.DatabaseError: ...
>>>
>>> con.close()
```
It fails because the PostgreSQL server doesn't allow this statement to have any
parameters. There are many SQL statements that one might think would have parameters,
but don't. For these cases the SQL has to be created manually, being careful to use the
`identifier()` and `literal()` functions to escape the values to avoid [SQL injection
attacks](https://en.wikipedia.org/wiki/SQL_injection>):
```python
>>> from pg8000.native import Connection, identifier, literal
>>>
>>> con = Connection("postgres", password="cpsnow")
>>>
>>> channel = 'top_secret'
>>> payload = 'Aliens Landed!'
>>> con.run(f"LISTEN {identifier(channel)}")
>>> con.run(f"NOTIFY {identifier(channel)}, {literal(payload)}")
>>>
>>> con.notifications[0]
(..., 'top_secret', 'Aliens Landed!')
>>>
>>> con.close()
```
### COPY FROM And TO A Stream
The SQL [COPY](https://www.postgresql.org/docs/current/sql-copy.html) statement can be
used to copy from and to a file or file-like object. Here's an example using the CSV
format:
```python
>>> import pg8000.native
>>> from io import StringIO
>>> import csv
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> # Create a CSV file in memory
>>>
>>> stream_in = StringIO()
>>> csv_writer = csv.writer(stream_in)
>>> csv_writer.writerow([1, "electron"])
12
>>> csv_writer.writerow([2, "muon"])
8
>>> csv_writer.writerow([3, "tau"])
7
>>> stream_in.seek(0)
0
>>>
>>> # Create a table and then copy the CSV into it
>>>
>>> con.run("CREATE TEMPORARY TABLE lepton (id SERIAL, name TEXT)")
>>> con.run("COPY lepton FROM STDIN WITH (FORMAT CSV)", stream=stream_in)
>>>
>>> # COPY from a table to a stream
>>>
>>> stream_out = StringIO()
>>> con.run("COPY lepton TO STDOUT WITH (FORMAT CSV)", stream=stream_out)
>>> stream_out.seek(0)
0
>>> for row in csv.reader(stream_out):
... print(row)
['1', 'electron']
['2', 'muon']
['3', 'tau']
>>>
>>> con.close()
```
It's also possible to COPY FROM an iterable, which is useful if you're creating rows
programmatically:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> # Generator function for creating rows
>>> def row_gen():
... for i, name in ((1, "electron"), (2, "muon"), (3, "tau")):
... yield f"{i},{name}\n"
>>>
>>> # Create a table and then copy the CSV into it
>>>
>>> con.run("CREATE TEMPORARY TABLE lepton (id SERIAL, name TEXT)")
>>> con.run("COPY lepton FROM STDIN WITH (FORMAT CSV)", stream=row_gen())
>>>
>>> # COPY from a table to a stream
>>>
>>> stream_out = StringIO()
>>> con.run("COPY lepton TO STDOUT WITH (FORMAT CSV)", stream=stream_out)
>>> stream_out.seek(0)
0
>>> for row in csv.reader(stream_out):
... print(row)
['1', 'electron']
['2', 'muon']
['3', 'tau']
>>>
>>> con.close()
```
### Execute Multiple SQL Statements
If you want to execute a series of SQL statements (eg. an `.sql` file), you can run
them as expected:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> statements = "SELECT 5; SELECT 'Erich Fromm';"
>>>
>>> con.run(statements)
[[5], ['Erich Fromm']]
>>>
>>> con.close()
```
The only caveat is that when executing multiple statements you can't have any
parameters.
### Quoted Identifiers in SQL
Say you had a column called `My Column`. Since it's case sensitive and contains a space,
you'd have to [surround it by double quotes
](https://www.postgresql.org/docs/current/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIER).
But you can't do:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("select 'hello' as "My Column"")
Traceback (most recent call last):
SyntaxError: invalid syntax...
>>>
>>> con.close()
```
since Python uses double quotes to delimit string literals, so one solution is
to use Python's [triple quotes
](https://docs.python.org/3/tutorial/introduction.html#strings) to delimit the string
instead:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run('''SELECT 'hello' AS "My Column"''')
[['hello']]
>>>
>>> con.close()
```
another solution, that's especially useful if the identifier comes from an untrusted
source, is to use the `identifier()` function, which correctly quotes and escapes the
identifier as needed:
```python
>>> from pg8000.native import Connection, identifier
>>>
>>> con = Connection("postgres", password="cpsnow")
>>>
>>> sql = f"SELECT 'hello' as {identifier('My Column')}"
>>> print(sql)
SELECT 'hello' as "My Column"
>>>
>>> con.run(sql)
[['hello']]
>>>
>>> con.close()
```
this approach guards against [SQL injection attacks
](https://en.wikipedia.org/wiki/SQL_injection). One thing to note if you're using
explicit schemas (eg. `pg_catalog.pg_language`) is that the schema name and table name
are both separate identifiers. So to escape them you'd do:
```python
>>> from pg8000.native import Connection, identifier
>>>
>>> con = Connection("postgres", password="cpsnow")
>>>
>>> query = (
... f"SELECT lanname FROM {identifier('pg_catalog')}.{identifier('pg_language')} "
... f"WHERE lanname = 'sql'"
... )
>>> print(query)
SELECT lanname FROM pg_catalog.pg_language WHERE lanname = 'sql'
>>>
>>> con.run(query)
[['sql']]
>>>
>>> con.close()
```
### Custom adapter from a Python type to a PostgreSQL type
pg8000 has a mapping from Python types to PostgreSQL types for when it needs to send
SQL parameters to the server. The default mapping that comes with pg8000 is designed to
work well in most cases, but you might want to add or replace the default mapping.
A Python `datetime.timedelta` object is sent to the server as a PostgreSQL
`interval` type, which has the `oid` 1186. But let's say we wanted to create our
own Python class to be sent as an `interval` type. Then we'd have to register an
adapter:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> class MyInterval(str):
... pass
>>>
>>> def my_interval_out(my_interval):
... return my_interval # Must return a str
>>>
>>> con.register_out_adapter(MyInterval, my_interval_out)
>>> con.run("SELECT CAST(:interval as interval)", interval=MyInterval("2 hours"))
[[datetime.timedelta(seconds=7200)]]
>>>
>>> con.close()
```
Note that it still came back as a `datetime.timedelta` object because we only changed
the mapping from Python to PostgreSQL. See below for an example of how to change the
mapping from PostgreSQL to Python.
### Custom adapter from a PostgreSQL type to a Python type
pg8000 has a mapping from PostgreSQL types to Python types for when it receives SQL
results from the server. The default mapping that comes with pg8000 is designed to work
well in most cases, but you might want to add or replace the default mapping.
If pg8000 receives PostgreSQL `interval` type, which has the `oid` 1186, it converts
it into a Python `datetime.timedelta` object. But let's say we wanted to create our
own Python class to be used instead of `datetime.timedelta`. Then we'd have to
register an adapter:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> class MyInterval(str):
... pass
>>>
>>> def my_interval_in(my_interval_str): # The parameter is of type str
... return MyInterval(my_interval)
>>>
>>> con.register_in_adapter(1186, my_interval_in)
>>> con.run("SELECT \'2 years'")
[['2 years']]
>>>
>>> con.close()
```
Note that registering the 'in' adapter only afects the mapping from the PostgreSQL type
to the Python type. See above for an example of how to change the mapping from
PostgreSQL to Python.
### Could Not Determine Data Type Of Parameter
Sometimes you'll get the `could not determine data type of parameter` error message from
the server:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("SELECT :v IS NULL", v=None)
Traceback (most recent call last):
pg8000.exceptions.DatabaseError: {'S': 'ERROR', 'V': 'ERROR', 'C': '42P18', 'M': 'could not determine data type of parameter $1', 'F': 'postgres.c', 'L': '...', 'R': '...'}
>>>
>>> con.close()
```
One way of solving it is to put a `CAST` in the SQL:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("SELECT cast(:v as TIMESTAMP) IS NULL", v=None)
[[True]]
>>>
>>> con.close()
```
Another way is to override the type that pg8000 sends along with each parameter:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> con.run("SELECT :v IS NULL", v=None, types={'v': pg8000.native.TIMESTAMP})
[[True]]
>>>
>>> con.close()
```
### Prepared Statements
[Prepared statements](https://www.postgresql.org/docs/current/sql-prepare.html) can be
useful in improving performance when you have a statement that's executed repeatedly.
Here's an example:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection("postgres", password="cpsnow")
>>>
>>> # Create the prepared statement
>>> ps = con.prepare("SELECT cast(:v as varchar)")
>>>
>>> # Execute the statement repeatedly
>>> ps.run(v="speedy")
[['speedy']]
>>> ps.run(v="rapid")
[['rapid']]
>>> ps.run(v="swift")
[['swift']]
>>>
>>> # Close the prepared statement, releasing resources on the server
>>> ps.close()
>>>
>>> con.close()
```
### Use Environment Variables As Connection Defaults
You might want to use the current user as the database username for example:
```python
>>> import pg8000.native
>>> import getpass
>>>
>>> # Connect to the database with current user name
>>> username = getpass.getuser()
>>> connection = pg8000.native.Connection(username, password="cpsnow")
>>>
>>> connection.run("SELECT 'pilau'")
[['pilau']]
>>>
>>> connection.close()
```
or perhaps you may want to use some of the same [environment variables that libpg uses
](https://www.postgresql.org/docs/current/libpq-envars.html):
```python
>>> import pg8000.native
>>> from os import environ
>>>
>>> username = environ.get('PGUSER', 'postgres')
>>> password = environ.get('PGPASSWORD', 'cpsnow')
>>> host = environ.get('PGHOST', 'localhost')
>>> port = environ.get('PGPORT', '5432')
>>> database = environ.get('PGDATABASE')
>>>
>>> connection = pg8000.native.Connection(
... username, password=password, host=host, port=port, database=database)
>>>
>>> connection.run("SELECT 'Mr Cairo'")
[['Mr Cairo']]
>>>
>>> connection.close()
```
It might be asked, why doesn't pg8000 have this behaviour built in? The thinking
follows the second aphorism of [The Zen of Python
](https://www.python.org/dev/peps/pep-0020/):
> Explicit is better than implicit.
So we've taken the approach of only being able to set connection parameters using the
`pg8000.native.Connection()` constructor.
### Connect To PostgreSQL Over SSL
By default the `ssl_context` connection parameter has the value `None` which means pg8000 will
attempt to connect to the server using SSL, and then fall back to a plain socket if the server
refuses SSL. If you want to *require* SSL (ie. to fail if it's not achieved) then you can set
`ssl_context=True`:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection('postgres', password="cpsnow", ssl_context=True)
>>> con.run("SELECT 'The game is afoot!'")
[['The game is afoot!']]
>>> con.close()
```
If on the other hand you want to connect over SSL with custom settings, set the `ssl_context`
parameter to an [`ssl.SSLContext`](https://docs.python.org/3/library/ssl.html#ssl.SSLContext) object:
```python
>>> import pg8000.native
>>> import ssl
>>>
>>> ssl_context = ssl.create_default_context()
>>> ssl_context.check_hostname = False
>>> ssl_context.verify_mode = ssl.CERT_NONE
>>> con = pg8000.native.Connection(
... 'postgres', password="cpsnow", ssl_context=ssl_context)
>>> con.run("SELECT 'Work is the curse of the drinking classes.'")
[['Work is the curse of the drinking classes.']]
>>> con.close()
```
It may be that your PostgreSQL server is behind an SSL proxy server in which case you
can give pg8000 the SSL socket with the `sock` parameter, and then set
`ssl_context=False` which means that no attempt will be made to create an SSL connection
to the server.
### Server-Side Cursors
You can use the SQL commands [DECLARE
](https://www.postgresql.org/docs/current/sql-declare.html),
[FETCH](https://www.postgresql.org/docs/current/sql-fetch.html),
[MOVE](https://www.postgresql.org/docs/current/sql-move.html) and
[CLOSE](https://www.postgresql.org/docs/current/sql-close.html) to manipulate
server-side cursors. For example:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection('postgres', password="cpsnow")
>>> con.run("START TRANSACTION")
>>> con.run("DECLARE c SCROLL CURSOR FOR SELECT * FROM generate_series(1, 100)")
>>> con.run("FETCH FORWARD 5 FROM c")
[[1], [2], [3], [4], [5]]
>>> con.run("MOVE FORWARD 50 FROM c")
>>> con.run("FETCH BACKWARD 10 FROM c")
[[54], [53], [52], [51], [50], [49], [48], [47], [46], [45]]
>>> con.run("CLOSE c")
>>> con.run("ROLLBACK")
>>>
>>> con.close()
```
### BLOBs (Binary Large Objects)
There's a set of [SQL functions
](https://www.postgresql.org/docs/current/lo-funcs.html) for manipulating BLOBs.
Here's an example:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection('postgres', password="cpsnow")
>>>
>>> # Create a BLOB and get its oid
>>> data = b'hello'
>>> res = con.run("SELECT lo_from_bytea(0, :data)", data=data)
>>> oid = res[0][0]
>>>
>>> # Create a table and store the oid of the BLOB
>>> con.run("CREATE TEMPORARY TABLE image (raster oid)")
>>>
>>> con.run("INSERT INTO image (raster) VALUES (:oid)", oid=oid)
>>> # Retrieve the data using the oid
>>> con.run("SELECT lo_get(:oid)", oid=oid)
[[b'hello']]
>>>
>>> # Add some data to the end of the BLOB
>>> more_data = b' all'
>>> offset = len(data)
>>> con.run(
... "SELECT lo_put(:oid, :offset, :data)",
... oid=oid, offset=offset, data=more_data)
[['']]
>>> con.run("SELECT lo_get(:oid)", oid=oid)
[[b'hello all']]
>>>
>>> # Download a part of the data
>>> con.run("SELECT lo_get(:oid, 6, 3)", oid=oid)
[[b'all']]
>>>
>>> con.close()
```
### Replication Protocol
The PostgreSQL [Replication Protocol
](https://www.postgresql.org/docs/current/protocol-replication.html) is supported using
the `replication` keyword when creating a connection:
```python
>>> import pg8000.native
>>>
>>> con = pg8000.native.Connection(
... 'postgres', password="cpsnow", replication="database")
>>>
>>> con.run("IDENTIFY_SYSTEM")
[['...', 1, '.../...', 'postgres']]
>>>
>>> con.close()
```
## DB-API 2 Interactive Examples
These examples stick to the DB-API 2.0 standard.
### Basic Example
Import pg8000, connect to the database, create a table, add some rows and then query the
table:
```python
>>> import pg8000.dbapi
>>>
>>> conn = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cursor = conn.cursor()
>>> cursor.execute("CREATE TEMPORARY TABLE book (id SERIAL, title TEXT)")
>>> cursor.execute(
... "INSERT INTO book (title) VALUES (%s), (%s) RETURNING id, title",
... ("Ender's Game", "Speaker for the Dead"))
>>> results = cursor.fetchall()
>>> for row in results:
... id, title = row
... print("id = %s, title = %s" % (id, title))
id = 1, title = Ender's Game
id = 2, title = Speaker for the Dead
>>> conn.commit()
>>>
>>> conn.close()
```
### Query Using Functions
Another query, using some PostgreSQL functions:
```python
>>> import pg8000.dbapi
>>>
>>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cursor = con.cursor()
>>>
>>> cursor.execute("SELECT TO_CHAR(TIMESTAMP '2021-10-10', 'YYYY BC')")
>>> cursor.fetchone()
['2021 AD']
>>>
>>> con.close()
```
### Interval Type
A query that returns the PostgreSQL interval type:
```python
>>> import datetime
>>> import pg8000.dbapi
>>>
>>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cursor = con.cursor()
>>>
>>> cursor.execute("SELECT timestamp '2013-12-01 16:06' - %s",
... (datetime.date(1980, 4, 27),))
>>> cursor.fetchone()
[datetime.timedelta(days=12271, seconds=57960)]
>>>
>>> con.close()
```
### Point Type
A round-trip with a [PostgreSQL point
](https://www.postgresql.org/docs/current/datatype-geometric.html) type:
```python
>>> import pg8000.dbapi
>>>
>>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cursor = con.cursor()
>>>
>>> cursor.execute("SELECT cast(%s as point)", ((2.3,1),))
>>> cursor.fetchone()
[(2.3, 1.0)]
>>>
>>> con.close()
```
### Numeric Parameter Style
pg8000 supports all the DB-API parameter styles. Here's an example of using the
'numeric' parameter style:
```python
>>> import pg8000.dbapi
>>>
>>> pg8000.dbapi.paramstyle = "numeric"
>>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cursor = con.cursor()
>>>
>>> cursor.execute("SELECT array_prepend(:1, CAST(:2 AS int[]))", (500, [1, 2, 3, 4],))
>>> cursor.fetchone()
[[500, 1, 2, 3, 4]]
>>> pg8000.dbapi.paramstyle = "format"
>>>
>>> con.close()
```
### Autocommit
Following the DB-API specification, autocommit is off by default. It can be turned on by
using the autocommit property of the connection:
```python
>>> import pg8000.dbapi
>>>
>>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> con.autocommit = True
>>>
>>> cur = con.cursor()
>>> cur.execute("vacuum")
>>> conn.autocommit = False
>>> cur.close()
>>>
>>> con.close()
```
### Client Encoding
When communicating with the server, pg8000 uses the character set that the server asks
it to use (the client encoding). By default the client encoding is the database's
character set (chosen when the database is created), but the client encoding can be
changed in a number of ways (eg. setting `CLIENT_ENCODING` in `postgresql.conf`).
Another way of changing the client encoding is by using an SQL command. For example:
```python
>>> import pg8000.dbapi
>>>
>>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cur = con.cursor()
>>> cur.execute("SET CLIENT_ENCODING TO 'UTF8'")
>>> cur.execute("SHOW CLIENT_ENCODING")
>>> cur.fetchone()
['UTF8']
>>> cur.close()
>>>
>>> con.close()
```
### JSON
JSON is sent to the server serialized, and returned de-serialized. Here's an example:
```python
>>> import json
>>> import pg8000.dbapi
>>>
>>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cur = con.cursor()
>>> val = ['Apollo 11 Cave', True, 26.003]
>>> cur.execute("SELECT cast(%s as json)", (json.dumps(val),))
>>> cur.fetchone()
[['Apollo 11 Cave', True, 26.003]]
>>> cur.close()
>>>
>>> con.close()
```
JSON queries can be have parameters:
```python
>>> import pg8000.dbapi
>>>
>>> with pg8000.dbapi.connect("postgres", password="cpsnow") as con:
... cur = con.cursor()
... cur.execute(""" SELECT CAST('{"a":1, "b":2}' AS jsonb) @> %s """, ({"b": 2},))
... for row in cur.fetchall():
... print(row)
[True]
```
### Retrieve Column Names From Results
Use the columns names retrieved from a query:
```python
>>> import pg8000
>>> conn = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> c = conn.cursor()
>>> c.execute("create temporary table quark (id serial, name text)")
>>> c.executemany("INSERT INTO quark (name) VALUES (%s)", (("Up",), ("Down",)))
>>> #
>>> # Now retrieve the results
>>> #
>>> c.execute("select * from quark")
>>> rows = c.fetchall()
>>> keys = [k[0] for k in c.description]
>>> results = [dict(zip(keys, row)) for row in rows]
>>> assert results == [{'id': 1, 'name': 'Up'}, {'id': 2, 'name': 'Down'}]
>>>
>>> conn.close()
```
### COPY from and to a file
The SQL [COPY](https://www.postgresql.org/docs/current/sql-copy.html) statement can
be used to copy from and to a file or file-like object:
```python
>>> from io import StringIO
>>> import pg8000.dbapi
>>>
>>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cur = con.cursor()
>>> #
>>> # COPY from a stream to a table
>>> #
>>> stream_in = StringIO('1\telectron\n2\tmuon\n3\ttau\n')
>>> cur = con.cursor()
>>> cur.execute("create temporary table lepton (id serial, name text)")
>>> cur.execute("COPY lepton FROM stdin", stream=stream_in)
>>> #
>>> # Now COPY from a table to a stream
>>> #
>>> stream_out = StringIO()
>>> cur.execute("copy lepton to stdout", stream=stream_out)
>>> stream_out.getvalue()
'1\telectron\n2\tmuon\n3\ttau\n'
>>>
>>> con.close()
```
### Server-Side Cursors
You can use the SQL commands [DECLARE
](https://www.postgresql.org/docs/current/sql-declare.html),
[FETCH](https://www.postgresql.org/docs/current/sql-fetch.html),
[MOVE](https://www.postgresql.org/docs/current/sql-move.html) and
[CLOSE](https://www.postgresql.org/docs/current/sql-close.html) to manipulate
server-side cursors. For example:
```python
>>> import pg8000.dbapi
>>>
>>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cur = con.cursor()
>>> cur.execute("START TRANSACTION")
>>> cur.execute(
... "DECLARE c SCROLL CURSOR FOR SELECT * FROM generate_series(1, 100)")
>>> cur.execute("FETCH FORWARD 5 FROM c")
>>> cur.fetchall()
([1], [2], [3], [4], [5])
>>> cur.execute("MOVE FORWARD 50 FROM c")
>>> cur.execute("FETCH BACKWARD 10 FROM c")
>>> cur.fetchall()
([54], [53], [52], [51], [50], [49], [48], [47], [46], [45])
>>> cur.execute("CLOSE c")
>>> cur.execute("ROLLBACK")
>>>
>>> con.close()
```
### BLOBs (Binary Large Objects)
There's a set of [SQL functions
](https://www.postgresql.org/docs/current/lo-funcs.html) for manipulating BLOBs.
Here's an example:
```python
>>> import pg8000.dbapi
>>>
>>> con = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cur = con.cursor()
>>>
>>> # Create a BLOB and get its oid
>>> data = b'hello'
>>> cur = con.cursor()
>>> cur.execute("SELECT lo_from_bytea(0, %s)", [data])
>>> oid = cur.fetchone()[0]
>>>
>>> # Create a table and store the oid of the BLOB
>>> cur.execute("CREATE TEMPORARY TABLE image (raster oid)")
>>> cur.execute("INSERT INTO image (raster) VALUES (%s)", [oid])
>>>
>>> # Retrieve the data using the oid
>>> cur.execute("SELECT lo_get(%s)", [oid])
>>> cur.fetchall()
([b'hello'],)
>>>
>>> # Add some data to the end of the BLOB
>>> more_data = b' all'
>>> offset = len(data)
>>> cur.execute("SELECT lo_put(%s, %s, %s)", [oid, offset, more_data])
>>> cur.execute("SELECT lo_get(%s)", [oid])
>>> cur.fetchall()
([b'hello all'],)
>>>
>>> # Download a part of the data
>>> cur.execute("SELECT lo_get(%s, 6, 3)", [oid])
>>> cur.fetchall()
([b'all'],)
>>>
>>> con.close()
```
### Parameter Limit
The protocol that PostgreSQL uses limits the number of parameters to 6,5535. The following will give
an error:
```python
>>> import pg8000.dbapi
>>>
>>> conn = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cursor = conn.cursor()
>>> SIZE = 100000
>>> cursor.execute(
... f"SELECT 1 WHERE 1 IN ({','.join(['%s'] * SIZE)})",
... [1] * SIZE,
... )
Traceback (most recent call last):
struct.error: 'H' format requires 0 <= number <= 65535
```
One way of working round this problem is to use the [unnest
](https://www.postgresql.org/docs/current/functions-array.html) function:
```python
>>> import pg8000.dbapi
>>>
>>> conn = pg8000.dbapi.connect(user="postgres", password="cpsnow")
>>> cursor = conn.cursor()
>>> SIZE = 100000
>>> cursor.execute(
... "SELECT 1 WHERE 1 IN (SELECT unnest(CAST(%s AS int[])))",
... [[1] * SIZE],
... )
>>> conn.close()
```
## Type Mapping
The following table shows the default mapping between Python types and PostgreSQL types,
and vice versa.
If pg8000 doesn't recognize a type that it receives from PostgreSQL, it will return it
as a ``str`` type. This is how pg8000 handles PostgreSQL ``enum`` and XML types. It's
possible to change the default mapping using adapters (see the examples).
| Python Type | PostgreSQL Type | Notes |
|-----------------------|-----------------|-----------------------------------------|
| bool | bool | |
| int | int4 | |
| str | text | |
| float | float8 | |
| decimal.Decimal | numeric | |
| bytes | bytea | |
| datetime.datetime (without tzinfo) | timestamp without timezone | +/-infinity PostgreSQL values are represented as Python `str` values. If a `timestamp` is too big for `datetime.datetime` then a `str` is used. |
| datetime.datetime (with tzinfo) | timestamp with timezone | +/-infinity PostgreSQL values are represented as Python `str` values. If a `timestamptz` is too big for `datetime.datetime` then a `str` is used. |
| datetime.date | date | +/-infinity PostgreSQL values are represented as Python `str` values. If a `date` is too big for a `datetime.date` then a `str` is used. |
| datetime.time | time without time zone | |
| datetime.timedelta | interval | If an ``interval`` is too big for `datetime.timedelta` then a `PGInterval` is used. |
| None | NULL | |
| uuid.UUID | uuid | |
| ipaddress.IPv4Address | inet | |
| ipaddress.IPv6Address | inet | |
| ipaddress.IPv4Network | inet | |
| ipaddress.IPv6Network | inet | |
| int | xid | |
| list of int | INT4[] | |
| list of float | FLOAT8[] | |
| list of bool | BOOL[] | |
| list of str | TEXT[] | |
| int | int2vector | Only from PostgreSQL to Python |
| JSON | json, jsonb | The Python JSON is provided as a Python serialized string. Results returned as de-serialized JSON. |
| pg8000.Range | range | PostgreSQL multirange types are | represented in Python as a list of range types. |
| tuple | composite type | Only from Python to PostgreSQL |
## Theory Of Operation
> A concept is tolerated inside the microkernel only if moving it outside the kernel,
> i.e., permitting competing implementations, would prevent the implementation of the
> system's required functionality.
>
> -- Jochen Liedtke, Liedtke's minimality principle
pg8000 is designed to be used with one thread per connection.
pg8000 communicates with the database using the [PostgreSQL Frontend/Backend Protocol
](https://www.postgresql.org/docs/current/protocol.html) (FEBE). If a query has no
parameters, pg8000 uses the 'simple query protocol'. If a query does have parameters,
pg8000 uses the 'extended query protocol' with unnamed prepared statements. The steps
for a query with parameters are:
1. Query comes in.
2. Send a PARSE message to the server to create an unnamed prepared statement.
3. Send a BIND message to run against the unnamed prepared statement, resulting in an
unnamed portal on the server.
4. Send an EXECUTE message to read all the results from the portal.
It's also possible to use named prepared statements. In which case the prepared
statement persists on the server, and represented in pg8000 using a
`PreparedStatement` object. This means that the PARSE step gets executed once up
front, and then only the BIND and EXECUTE steps are repeated subsequently.
There are a lot of PostgreSQL data types, but few primitive data types in Python. By
default, pg8000 doesn't send PostgreSQL data type information in the PARSE step, in
which case PostgreSQL assumes the types implied by the SQL statement. In some cases
PostgreSQL can't work out a parameter type and so an [explicit cast
](https://www.postgresql.org/docs/current/static/sql-expressions.html#SQL-SYNTAX-TYPE-CASTS)
can be used in the SQL.
In the FEBE protocol, each query parameter can be sent to the server either as binary
or text according to the format code. In pg8000 the parameters are always sent as text.
Occasionally, the network connection between pg8000 and the server may go down. If
pg8000 encounters a network problem it'll raise an `InterfaceError` with the message
`network error` and with the original exception set as the [cause
](https://docs.python.org/3/reference/simple_stmts.html#the-raise-statement).
## Native API Docs
### pg8000.native.Error
Generic exception that is the base exception of the other error exceptions.
### pg8000.native.InterfaceError
For errors that originate within pg8000.
### pg8000.native.DatabaseError
For errors that originate from the server.
### pg8000.native.Connection(user, host='localhost', database=None, port=5432, password=None, source\_address=None, unix\_sock=None, ssl\_context=None, timeout=None, tcp\_keepalive=True, application\_name=None, replication=None, sock=None)
Creates a connection to a PostgreSQL database.
- *user* - The username to connect to the PostgreSQL server with. If your server character encoding is not `ascii` or `utf8`, then you need to provide `user` as bytes, eg. `'my_name'.encode('EUC-JP')`.
- *host* - The hostname of the PostgreSQL server to connect with. Providing this parameter is necessary for TCP/IP connections. One of either `host` or `unix_sock` must be provided. The default is `localhost`.
- *database* - The name of the database instance to connect with. If `None` then the PostgreSQL server will assume the database name is the same as the username. If your server character encoding is not `ascii` or `utf8`, then you need to provide `database` as bytes, eg. `'my_db'.encode('EUC-JP')`.
- *port* - The TCP/IP port of the PostgreSQL server instance. This parameter defaults to `5432`, the registered common port of PostgreSQL TCP/IP servers.
- *password* - The user password to connect to the server with. This parameter is optional; if omitted and the database server requests password-based authentication, the connection will fail to open. If this parameter is provided but not requested by the server, no error will occur. If your server character encoding is not `ascii` or `utf8`, then you need to provide `password` as bytes, eg. `'my_password'.encode('EUC-JP')`.
- *source_address* - The source IP address which initiates the connection to the PostgreSQL server. The default is `None` which means that the operating system will choose the source address.
- *unix_sock* - The path to the UNIX socket to access the database through, for example, `'/tmp/.s.PGSQL.5432'`. One of either `host` or `unix_sock` must be provided.
- *ssl_context* - This governs SSL encryption for TCP/IP sockets. It can have four values:
- `None`, the default, meaning that an attempt will be made to connect over SSL, but if this is rejected by the server then pg8000 will fall back to using a plain socket.
- `True`, means use SSL with an `ssl.SSLContext` with the minimum of checks.
- `False`, means to not attempt to create an SSL socket.
- An instance of `ssl.SSLContext` which will be used to create the SSL connection.
- *timeout* - This is the time in seconds before the connection to the server will time out. The default is `None` which means no timeout.
- *tcp_keepalive* - If `True` then use [TCP keepalive](https://en.wikipedia.org/wiki/Keepalive#TCP_keepalive). The default is `True`.
- *application_name* - Sets the [application\_name](https://www.postgresql.org/docs/current/runtime-config-logging.html#GUC-APPLICATION-NAME). If your server character encoding is not `ascii` or `utf8`, then you need to provide values as bytes, eg. `'my_application_name'.encode('EUC-JP')`. The default is `None` which means that the server will set the application name.
- *replication* - Used to run in [streaming replication mode](https://www.postgresql.org/docs/current/protocol-replication.html). If your server character encoding is not `ascii` or `utf8`, then you need to provide values as bytes, eg. `'database'.encode('EUC-JP')`.
- *sock* - A socket-like object to use for the connection. For example, `sock` could be a plain `socket.socket`, or it could represent an SSH tunnel or perhaps an `ssl.SSLSocket` to an SSL proxy. If an `ssl.SSLContext` is provided, then it will be used to attempt to create an SSL socket from the provided socket.
### pg8000.native.Connection.notifications
A deque of server-side
[notifications](https://www.postgresql.org/docs/current/sql-notify.html) received by
this database connection (via the `LISTEN` / `NOTIFY` PostgreSQL commands). Each list
item is a three-element tuple containing the PostgreSQL backend PID that issued the
notify, the channel and the payload.
### pg8000.native.Connection.notices
A deque of server-side notices received by this database connection.
### pg8000.native.Connection.parameter\_statuses
A `dict` of server-side parameter statuses received by this database connection.
### pg8000.native.Connection.run(sql, stream=None, types=None, \*\*kwargs)
Executes an sql statement, and returns the results as a `list`. For example:
```
con.run("SELECT * FROM cities where population > :pop", pop=10000)
```
- *sql* - The SQL statement to execute. Parameter placeholders appear as a `:` followed by the parameter name.
- *stream* - For use with the PostgreSQL [COPY](http://www.postgresql.org/docs/current/static/sql-copy.html) command. The nature of the parameter depends on whether the SQL command is `COPY FROM` or `COPY TO`.
- `COPY FROM` - The stream parameter must be a readable file-like object or an iterable. If it's an
iterable then the items can be ``str`` or binary.
- `COPY TO` - The stream parameter must be a writable file-like object.
- *types* - A dictionary of oids. A key corresponds to a parameter.
- *kwargs* - The parameters of the SQL statement.
### pg8000.native.Connection.row\_count
This read-only attribute contains the number of rows that the last `run()` method
produced (for query statements like ``SELECT``) or affected (for modification statements
like `UPDATE`.
The value is -1 if:
- No `run()` method has been performed yet.
- There was no rowcount associated with the last `run()`.
### pg8000.native.Connection.columns
A list of column metadata. Each item in the list is a dictionary with the following
keys:
- name
- table\_oid
- column\_attrnum
- type\_oid
- type\_size
- type\_modifier
- format
### pg8000.native.Connection.close()
Closes the database connection.
### pg8000.native.Connection.register\_out\_adapter(typ, out\_func)
Register a type adapter for types going out from pg8000 to the server.
- *typ* - The Python class that the adapter is for.
- *out_func* - A function that takes the Python object and returns its string representation in the format that the server requires.
### pg8000.native.Connection.register\_in\_adapter(oid, in\_func)
Register a type adapter for types coming in from the server to pg8000.
- *oid* - The PostgreSQL type identifier found in the [pg\_type system catalog](https://www.postgresql.org/docs/current/catalog-pg-type.html).
- *in_func* - A function that takes the PostgreSQL string representation and returns a corresponding
Python object.
### pg8000.native.Connection.prepare(sql)
Returns a `PreparedStatement` object which represents a [prepared statement
](https://www.postgresql.org/docs/current/sql-prepare.html) on the server. It can
subsequently be repeatedly executed.
- *sql* - The SQL statement to prepare. Parameter placeholders appear as a `:` followed by the parameter name.
### pg8000.native.PreparedStatement
A prepared statement object is returned by the `pg8000.native.Connection.prepare()`
method of a connection. It has the following methods:
#### pg8000.native.PreparedStatement.run(\*\*kwargs)
Executes the prepared statement, and returns the results as a `tuple`.
- *kwargs* - The parameters of the prepared statement.
#### pg8000.native.PreparedStatement.close()
Closes the prepared statement, releasing the prepared statement held on the server.
### pg8000.native.identifier(ident)
Correctly quotes and escapes a string to be used as an [SQL identifier
](https://www.postgresql.org/docs/current/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIERS).
- *ident* - The `str` to be used as an SQL identifier.
### pg8000.native.literal(value)
Correctly quotes and escapes a value to be used as an [SQL literal
](https://www.postgresql.org/docs/current/sql-syntax-lexical.html#SQL-SYNTAX-CONSTANTS).
- *value* - The value to be used as an SQL literal.
## DB-API 2 Docs
### Properties
#### pg8000.dbapi.apilevel
The DBAPI level supported, currently "2.0".
#### pg8000.dbapi.threadsafety
Integer constant stating the level of thread safety the DBAPI interface supports. For
pg8000, the threadsafety value is 1, meaning that threads may share the module but not
connections.
#### pg8000.dbapi.paramstyle
String property stating the type of parameter marker formatting expected by
the interface. This value defaults to "format", in which parameters are
marked in this format: "WHERE name=%s".
As an extension to the DBAPI specification, this value is not constant; it can be
changed to any of the following values:
- *qmark* - Question mark style, eg. `WHERE name=?`
- *numeric* - Numeric positional style, eg. `WHERE name=:1`
- *named* - Named style, eg. `WHERE name=:paramname`
- *format* - printf format codes, eg. `WHERE name=%s`
- *pyformat* - Python format codes, eg. `WHERE name=%(paramname)s`
#### pg8000.dbapi.STRING
String type oid.
#### pg8000.dbapi.BINARY
#### pg8000.dbapi.NUMBER
Numeric type oid.
#### pg8000.dbapi.DATETIME
Timestamp type oid
#### pg8000.dbapi.ROWID
ROWID type oid
### Functions
#### pg8000.dbapi.connect(user, host='localhost', database=None, port=5432, password=None, source\_address=None, unix\_sock=None, ssl\_context=None, timeout=None, tcp\_keepalive=True, applicationa_name=None, replication=None, sock=None)
Creates a connection to a PostgreSQL database.
- *user* - The username to connect to the PostgreSQL server with. If your server character encoding is not `ascii` or `utf8`, then you need to provide `user` as bytes, eg. `'my_name'.encode('EUC-JP')`.
- *host* - The hostname of the PostgreSQL server to connect with. Providing this parameter is necessary for TCP/IP connections. One of either `host` or `unix_sock` must be provided. The default is `localhost`.
- *database* - The name of the database instance to connect with. If `None` then the PostgreSQL server will assume the database name is the same as the username. If your server character encoding is not `ascii` or `utf8`, then you need to provide `database` as bytes, eg. `'my_db'.encode('EUC-JP')`.
- *port* - The TCP/IP port of the PostgreSQL server instance. This parameter defaults to `5432`, the registered common port of PostgreSQL TCP/IP servers.
- *password* - The user password to connect to the server with. This parameter is optional; if omitted and the database server requests password-based authentication, the connection will fail to open. If this parameter is provided but not requested by the server, no error will occur. If your server character encoding is not `ascii` or `utf8`, then you need to provide `password` as bytes, eg. `'my_password'.encode('EUC-JP')`.
- *source_address* - The source IP address which initiates the connection to the PostgreSQL server. The default is `None` which means that the operating system will choose the source address.
- *unix_sock* - The path to the UNIX socket to access the database through, for example, `'/tmp/.s.PGSQL.5432'`. One of either `host` or `unix_sock` must be provided.
- *ssl_context* - This governs SSL encryption for TCP/IP sockets. It can have four values:
- `None`, the default, meaning that an attempt will be made to connect over SSL, but if this is rejected by the server then pg8000 will fall back to using a plain socket.
- `True`, means use SSL with an `ssl.SSLContext` with the minimum of checks.
- `False`, means to not attempt to create an SSL socket.
- An instance of `ssl.SSLContext` which will be used to create the SSL connection.
- *timeout* - This is the time in seconds before the connection to the server will time out. The default is `None` which means no timeout.
- *tcp_keepalive* - If `True` then use [TCP keepalive](https://en.wikipedia.org/wiki/Keepalive#TCP_keepalive). The default is `True`.
- *application_name* - Sets the [application\_name](https://www.postgresql.org/docs/current/runtime-config-logging.html#GUC-APPLICATION-NAME). If your server character encoding is not `ascii` or `utf8`, then you need to provide values as bytes, eg. `'my_application_name'.encode('EUC-JP')`. The default is `None` which means that the server will set the application name.
- *replication* - Used to run in [streaming replication mode](https://www.postgresql.org/docs/current/protocol-replication.html). If your server character encoding is not `ascii` or `utf8`, then you need to provide values as bytes, eg. `'database'.encode('EUC-JP')`.
- *sock* - A socket-like object to use for the connection. For example, `sock` could be a plain `socket.socket`, or it could represent an SSH tunnel or perhaps an `ssl.SSLSocket` to an SSL proxy. If an `ssl.SSLContext` is provided, then it will be used to attempt to create an SSL socket from the provided socket.
#### pg8000.dbapi.Date(year, month, day)
Construct an object holding a date value.
This property is part of the `DBAPI 2.0 specification
<http://www.python.org/dev/peps/pep-0249/>`_.
Returns: `datetime.date`
#### pg8000.dbapi.Time(hour, minute, second)
Construct an object holding a time value.
Returns: `datetime.time`
#### pg8000.dbapi.Timestamp(year, month, day, hour, minute, second)
Construct an object holding a timestamp value.
Returns: `datetime.datetime`
#### pg8000.dbapi.DateFromTicks(ticks)
Construct an object holding a date value from the given ticks value (number of seconds
since the epoch).
Returns: `datetime.datetime`
#### pg8000.dbapi.TimeFromTicks(ticks)
Construct an object holding a time value from the given ticks value (number of seconds
since the epoch).
Returns: `datetime.time`
#### pg8000.dbapi.TimestampFromTicks(ticks)
Construct an object holding a timestamp value from the given ticks value (number of
seconds since the epoch).
Returns: `datetime.datetime`
#### pg8000.dbapi.Binary(value)
Construct an object holding binary data.
Returns: `bytes`
### Generic Exceptions
Pg8000 uses the standard DBAPI 2.0 exception tree as "generic" exceptions. Generally,
more specific exception types are raised; these specific exception types are derived
from the generic exceptions.
#### pg8000.dbapi.Warning
Generic exception raised for important database warnings like data truncations. This
exception is not currently used by pg8000.
#### pg8000.dbapi.Error
Generic exception that is the base exception of all other error exceptions.
#### pg8000.dbapi.InterfaceError
Generic exception raised for errors that are related to the database interface rather
than the database itself. For example, if the interface attempts to use an SSL
connection but the server refuses, an InterfaceError will be raised.
#### pg8000.dbapi.DatabaseError
Generic exception raised for errors that are related to the database. This exception is
currently never raised by pg8000.
#### pg8000.dbapi.DataError
Generic exception raised for errors that are due to problems with the processed data.
This exception is not currently raised by pg8000.
#### pg8000.dbapi.OperationalError
Generic exception raised for errors that are related to the database's operation and not
necessarily under the control of the programmer. This exception is currently never
raised by pg8000.
#### pg8000.dbapi.IntegrityError
Generic exception raised when the relational integrity of the database is affected. This
exception is not currently raised by pg8000.
#### pg8000.dbapi.InternalError
Generic exception raised when the database encounters an internal error. This is
currently only raised when unexpected state occurs in the pg8000 interface itself, and
is typically the result of a interface bug.
#### pg8000.dbapi.ProgrammingError
Generic exception raised for programming errors. For example, this exception is raised
if more parameter fields are in a query string than there are available parameters.
#### pg8000.dbapi.NotSupportedError
Generic exception raised in case a method or database API was used which is not
supported by the database.
### Classes
#### pg8000.dbapi.Connection
A connection object is returned by the `pg8000.dbapi.connect()` function. It represents a
single physical connection to a PostgreSQL database.
#### pg8000.dbapi.Connection.autocommit
Following the DB-API specification, autocommit is off by default. It can be turned on by
setting this boolean pg8000-specific autocommit property to ``True``.
#### pg8000.dbapi.Connection.close()
Closes the database connection.
#### pg8000.dbapi.Connection.cursor()
Creates a `pg8000.dbapi.Cursor` object bound to this connection.
#### pg8000.dbapi.Connection.rollback()
Rolls back the current database transaction.
#### pg8000.dbapi.Connection.tpc_begin(xid)
Begins a TPC transaction with the given transaction ID xid. This method should be
called outside of a transaction (i.e. nothing may have executed since the last
`commit()` or `rollback()`. Furthermore, it is an error to call `commit()` or
`rollback()` within the TPC transaction. A `ProgrammingError` is raised, if the
application calls `commit()` or `rollback()` during an active TPC transaction.
#### pg8000.dbapi.Connection.tpc_commit(xid=None)
When called with no arguments, `tpc_commit()` commits a TPC transaction previously
prepared with `tpc_prepare()`. If `tpc_commit()` is called prior to
`tpc_prepare()`, a single phase commit is performed. A transaction manager may choose
to do this if only a single resource is participating in the global transaction.
When called with a transaction ID `xid`, the database commits the given transaction.
If an invalid transaction ID is provided, a `ProgrammingError` will be raised. This
form should be called outside of a transaction, and is intended for use in recovery.
On return, the TPC transaction is ended.
#### pg8000.dbapi.Connection.tpc_prepare()
Performs the first phase of a transaction started with `.tpc_begin()`. A
`ProgrammingError` is be raised if this method is called outside of a TPC transaction.
After calling `tpc_prepare()`, no statements can be executed until `tpc_commit()` or
`tpc_rollback()` have been called.
#### pg8000.dbapi.Connection.tpc_recover()
Returns a list of pending transaction IDs suitable for use with `tpc_commit(xid)` or
`tpc_rollback(xid)`.
#### pg8000.dbapi.Connection.tpc_rollback(xid=None)
When called with no arguments, `tpc_rollback()` rolls back a TPC transaction. It may
be called before or after `tpc_prepare()`.
When called with a transaction ID xid, it rolls back the given transaction. If an
invalid transaction ID is provided, a `ProgrammingError` is raised. This form should
be called outside of a transaction, and is intended for use in recovery.
On return, the TPC transaction is ended.
#### pg8000.dbapi.Connection.xid(format_id, global_transaction_id, branch_qualifier)
Create a Transaction IDs (only global_transaction_id is used in pg) format_id and
branch_qualifier are not used in postgres global_transaction_id may be any string
identifier supported by postgres returns a tuple (format_id, global_transaction_id,
branch_qualifier)
#### pg8000.dbapi.Cursor
A cursor object is returned by the `pg8000.dbapi.Connection.cursor()` method of a
connection. It has the following attributes and methods:
##### pg8000.dbapi.Cursor.arraysize
This read/write attribute specifies the number of rows to fetch at a time with
`pg8000.dbapi.Cursor.fetchmany()`. It defaults to 1.
##### pg8000.dbapi.Cursor.connection
This read-only attribute contains a reference to the connection object (an instance of
`pg8000.dbapi.Connection`) on which the cursor was created.
##### pg8000.dbapi.Cursor.rowcount
This read-only attribute contains the number of rows that the last `execute()` or
`executemany()` method produced (for query statements like `SELECT`) or affected
(for modification statements like `UPDATE`.
The value is -1 if:
- No `execute()` or `executemany()` method has been performed yet on the cursor.
- There was no rowcount associated with the last `execute()`.
- At least one of the statements executed as part of an `executemany()` had no row
count associated with it.
##### pg8000.dbapi.Cursor.description
This read-only attribute is a sequence of 7-item sequences. Each value contains
information describing one result column. The 7 items returned for each column are
(name, type_code, display_size, internal_size, precision, scale, null_ok). Only the
first two values are provided by the current implementation.
##### pg8000.dbapi.Cursor.close()
Closes the cursor.
##### pg8000.dbapi.Cursor.execute(operation, args=None, stream=None)
Executes a database operation. Parameters may be provided as a sequence, or as a
mapping, depending upon the value of `pg8000.dbapi.paramstyle`. Returns the cursor,
which may be iterated over.
- *operation* - The SQL statement to execute.
- *args* - If `pg8000.dbapi.paramstyle` is `qmark`, `numeric`, or `format`, this argument should be an array of parameters to bind into the statement. If `pg8000.dbapi.paramstyle` is `named`, the argument should be a `dict` mapping of parameters. If `pg8000.dbapi.paramstyle` is `pyformat`, the argument value may be either an array or a mapping.
- *stream* - This is a pg8000 extension for use with the PostgreSQL [COPY](http://www.postgresql.org/docs/current/static/sql-copy.html) command. For a `COPY FROM` the parameter must be a readable file-like object, and for `COPY TO` it must be writable.
##### pg8000.dbapi.Cursor.executemany(operation, param_sets)
Prepare a database operation, and then execute it against all parameter sequences or
mappings provided.
- *operation* - The SQL statement to execute.
- *parameter_sets* - A sequence of parameters to execute the statement with. The values in the sequence should be sequences or mappings of parameters, the same as the args argument of the `pg8000.dbapi.Cursor.execute()` method.
##### pg8000.dbapi.Cursor.callproc(procname, parameters=None)
Call a stored database procedure with the given name and optional parameters.
- *procname* - The name of the procedure to call.
- *parameters* - A list of parameters.
##### pg8000.dbapi.Cursor.fetchall()
Fetches all remaining rows of a query result.
Returns: A sequence, each entry of which is a sequence of field values making up a row.
##### pg8000.dbapi.Cursor.fetchmany(size=None)
Fetches the next set of rows of a query result.
- *size* - The number of rows to fetch when called. If not provided, the `pg8000.dbapi.Cursor.arraysize` attribute value is used instead.
Returns: A sequence, each entry of which is a sequence of field values making up a row.
If no more rows are available, an empty sequence will be returned.
##### pg8000.dbapi.Cursor.fetchone()
Fetch the next row of a query result set.
Returns: A row as a sequence of field values, or `None` if no more rows are available.
##### pg8000.dbapi.Cursor.setinputsizes(\*sizes)
Used to set the parameter types of the next query. This is useful if it's difficult for
pg8000 to work out the types from the parameters themselves (eg. for parameters of type
None).
- *sizes* - Positional parameters that are either the Python type of the parameter to be sent, or the PostgreSQL oid. Common oids are available as constants such as `pg8000.STRING`, `pg8000.INTEGER`, `pg8000.TIME` etc.
##### pg8000.dbapi.Cursor.setoutputsize(size, column=None)
Not implemented by pg8000.
#### pg8000.dbapi.Interval
An Interval represents a measurement of time. In PostgreSQL, an interval is defined in
the measure of months, days, and microseconds; as such, the pg8000 interval type
represents the same information.
Note that values of the `pg8000.dbapi.Interval.microseconds`,
`pg8000.dbapi.Interval.days`, and `pg8000.dbapi.Interval.months` properties are
independently measured and cannot be converted to each other. A month may be 28, 29, 30,
or 31 days, and a day may occasionally be lengthened slightly by a leap second.
## Design Decisions
For the `Range` type, the constructor follows the [PostgreSQL range constructor functions
](https://www.postgresql.org/docs/current/rangetypes.html#RANGETYPES-CONSTRUCT)
which makes [[closed, open)](https://fhur.me/posts/always-use-closed-open-intervals)
the easiest to express:
```python
>>> from pg8000.types import Range
>>>
>>> pg_range = Range(2, 6)
```
## Tests
- Install [tox](http://testrun.org/tox/latest/): `pip install tox`
- Enable the PostgreSQL hstore extension by running the SQL command:
`create extension hstore;`
- Add a line to `pg_hba.conf` for the various authentication options:
```
host pg8000_md5 all 127.0.0.1/32 md5
host pg8000_gss all 127.0.0.1/32 gss
host pg8000_password all 127.0.0.1/32 password
host pg8000_scram_sha_256 all 127.0.0.1/32 scram-sha-256
host all all 127.0.0.1/32 trust
```
- Set password encryption to `scram-sha-256` in `postgresql.conf`:
`password_encryption = 'scram-sha-256'`
- Set the password for the postgres user: `ALTER USER postgresql WITH PASSWORD 'pw';`
- Run `tox` from the `pg8000` directory: `tox`
This will run the tests against the Python version of the virtual environment, on the
machine, and the installed PostgreSQL version listening on port 5432, or the `PGPORT`
environment variable if set.
Benchmarks are run as part of the test suite at `tests/test_benchmarks.py`.
## Doing A Release Of pg8000
Run `tox` to make sure all tests pass, then update the release notes, then do:
```
git tag -a x.y.z -m "version x.y.z"
rm -r dist
python -m build
twine upload dist/*
```
## Release Notes
### Version 1.31.2, 2024-04-28
- Fix bug where `parameter_statuses` fails for non-ascii encoding.
- Add support for Python 3.12
### Version 1.31.1, 2024-04-01
- Move to src style layout, and also for packaging use Hatch rather than setuptools. This means that if the source distribution has a directory added to it (as is needed for packaging for OS distributions) the package can still be built.
### Version 1.31.0, 2024-03-31
- Now the `ssl_context` connection parameter can have one of four values:
- None - The default, meaning it'll try and connect over SSL but fall back to a plain socket if not.
- True - Will try and connect over SSL and fail if not.
- False - It'll not try to connect over SSL.
- SSLContext object - It'll use this object to connect over SSL.
### Version 1.30.5, 2024-02-22
- Fix bug that now means the number of parameters cam be as high as an unsigned 16 bit
integer will go.
### Version 1.30.4, 2024-01-03
- Add support for more range and multirange types.
- Make the `Connection.parameter_statuses` property a `dict` rather than a `dequeue`.
### Version 1.30.3, 2023-10-31
- Fix problem with PG date overflowing Python types. Now we return the `str` we got from the
server if we can't parse it.
### Version 1.30.2, 2023-09-17
- Bug fix where dollar-quoted string constants weren't supported.
### Version 1.30.1, 2023-07-29
- There was a problem uploading the previous version (1.30.0) to PyPI because the markup of the README.rst was invalid. There's now a step in the automated tests to check for this.
### Version 1.30.0, 2023-07-27
- Remove support for Python 3.7
- Add a `sock` keyword parameter for creating a connection from a pre-configured socket.
### Version 1.29.8, 2023-06-16
- Ranges don't work with legacy API.
### Version 1.29.7, 2023-06-16
- Add support for PostgreSQL `range` and `multirange` types. Previously pg8000 would just return them as strings, but now they're returned as `Range` and lists of `Range`.
- The PostgreSQL `record` type is now returned as a `tuple` of strings, whereas before it was returned as one string.
### Version 1.29.6, 2023-05-29
- Fixed two bugs with composite types. Nulls should be represented by an empty string, and in an array of composite types, the elements should be surrounded by double quotes.
### Version 1.29.5, 2023-05-09
- Fixed bug where pg8000 didn't handle the case when the number of bytes received from a socket was fewer than requested. This was being interpreted as a network error, but in fact we just needed to wait until more bytes were available.
- When using the `PGInterval` type, if a response from the server contained the period `millennium`, it wasn't recognised. This was caused by a spelling mistake where we had `millenium` rather than `millennium`.
- Added support for sending PostgreSQL composite types. If a value is sent as a `tuple`, pg8000 will send it to the server as a `(` delimited composite string.
### Version 1.29.4, 2022-12-14
- Fixed bug in `pg8000.dbapi` in the `setinputsizes()` method where if a `size` was a recognized Python type, the method failed.
### Version 1.29.3, 2022-10-26
- Upgrade the SCRAM library to version 1.4.3. This adds support for the case where the client supports channel binding but the server doesn't.
### Version 1.29.2, 2022-10-09
- Fixed a bug where in a literal array, items such as `\n` and `\r` weren't escaped properly before being sent to the server.
- Fixed a bug where if the PostgreSQL server has a half-hour time zone set, values of type `timestamp with time zone` failed. This has been fixed by using the `parse` function of the `dateutil` package if the `datetime` parser fails.
### Version 1.29.1, 2022-05-23
- In trying to determine if there's been a failed commit, check for `ROLLBACK TO SAVEPOINT`.
### Version 1.29.0, 2022-05-21
- Implement a workaround for the [silent failed commit](https://github.com/tlocke/pg8000/issues/36) bug.
- Previously if an empty string was sent as the query an exception would be raised, but that isn't done now.
### Version 1.28.3, 2022-05-18
- Put back `__version__` attributes that were inadvertently removed.
### Version 1.28.2, 2022-05-17
- Use a build system that's compliant with PEP517.
### Version 1.28.1, 2022-05-17
- If when doing a `COPY FROM` the `stream` parameter is an iterator of `str`, pg8000 used to silently append a newline to the end. That no longer happens.
### Version 1.28.0, 2022-05-17
- When using the `COPY FROM` SQL statement, allow the `stream` parameter to be an iterable.
### Version 1.27.1, 2022-05-16
- The `seconds` attribute of `PGInterval` is now always a `float`, to cope with fractional seconds.
- Updated the `interval` parsers for `iso_8601` and `sql_standard` to take account of fractional seconds.
### Version 1.27.0, 2022-05-16
- It used to be that by default, if pg8000 received an `interval` type from the server and it was too big to fit into a `datetime.timedelta` then an exception would be raised. Now if an interval is too big for `datetime.timedelta` a `PGInterval` is returned.
- pg8000 now supports all the output formats for an `interval` (`postgres`, `postgres_verbose`, `iso_8601` and `sql_standard`).
### Version 1.26.1, 2022-04-23
- Make sure all tests are run by the GitHub Actions tests on commit.
- Remove support for Python 3.6
- Remove support for PostgreSQL 9.6
### Version 1.26.0, 2022-04-18
- When connecting, raise an `InterfaceError('network error')` rather than let the underlying `struct.error` float up.
- Make licence text the same as that used by the OSI. Previously the licence wording differed slightly from the BSD 3 Clause licence at https://opensource.org/licenses/BSD-3-Clause. This meant that automated tools didn't pick it up as being Open Source. The changes are believed to not alter the meaning of the license at all.
### Version 1.25.0, 2022-04-17
- Fix more cases where a `ResourceWarning` would be raise because of a socket that had been left open.
- We now have a single `InterfaceError` with the message 'network error' for all network errors, with the underlying exception held in the `cause` of the exception.
### Version 1.24.2, 2022-04-15
- To prevent a `ResourceWarning` close socket if a connection can't be created.
### Version 1.24.1, 2022-03-02
- Return pg +/-infinity dates as `str`. Previously +/-infinity pg values would cause an error when returned, but now we return +/-infinity as strings.
### Version 1.24.0, 2022-02-06
- Add SQL escape functions identifier() and literal() to the native API. For use when a query can't be parameterised and the SQL string has to be created using untrusted values.
### Version 1.23.0, 2021-11-13
- If a query has no parameters, then the query will no longer be parsed. Although there are performance benefits for doing this, the main reason is to avoid query rewriting, which can introduce errors.
### Version 1.22.1, 2021-11-10
- Fix bug in PGInterval type where `str()` failed for a millennia value.
### Version 1.22.0, 2021-10-13
- Rather than specifying the oids in the `Parse` step of the Postgres protocol, pg8000 now omits them, and so Postgres will use the oids it determines from the query. This makes the pg8000 code simpler and also it should also make the nuances of type matching more straightforward.
|