Skip to content

Commit 75dee5d

Browse files
committed
Python/SQLAlchemy: Demonstrate support for asyncpg and psycopg
The `sqlalchemy-cratedb` package supports the vanilla HTTP-based transport using urllib3, and the standard PostgreSQL drivers `asyncpg` and `psycopg`.
1 parent 3f15707 commit 75dee5d

File tree

6 files changed

+552
-1
lines changed

6 files changed

+552
-1
lines changed

by-language/python-sqlalchemy/README.rst

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -92,6 +92,10 @@ Run example programs::
9292

9393
time python insert_dask.py
9494

95+
time python sync_table.py urllib3 psycopg
96+
time python async_table.py psycopg asyncpg
97+
time python async_streaming.py psycopg asyncpg
98+
9599
Use ``insert_pandas.py`` to connect to any other database instance::
96100

97101
export DBURI="crate://crate@localhost:4200/"
Lines changed: 174 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,174 @@
1+
"""
2+
About
3+
=====
4+
5+
Example program to demonstrate how to connect to CrateDB using its SQLAlchemy
6+
dialect, and exercise a few basic examples using the low-level table API, this
7+
time in asynchronous mode.
8+
9+
Specific to the asynchronous mode of SQLAlchemy is the streaming of results:
10+
11+
> The `AsyncConnection` also features a "streaming" API via the `AsyncConnection.stream()`
12+
> method that returns an `AsyncResult` object. This result object uses a server-side cursor
13+
> and provides an async/await API, such as an async iterator.
14+
>
15+
> -- https://docs.sqlalchemy.org/en/20/orm/extensions/asyncio.html#synopsis-core
16+
17+
Both the PostgreSQL drivers based on `psycopg` and `asyncpg` are exercised.
18+
The corresponding SQLAlchemy dialect identifiers are::
19+
20+
# PostgreSQL protocol on port 5432, using `psycopg`
21+
crate+psycopg://crate@localhost:5432/doc
22+
23+
# PostgreSQL protocol on port 5432, using `asyncpg`
24+
crate+asyncpg://crate@localhost:5432/doc
25+
26+
Synopsis
27+
========
28+
::
29+
30+
# Run CrateDB
31+
docker run --rm -it --publish=4200:4200 --publish=5432:5432 crate
32+
33+
# Use PostgreSQL protocol, with asynchronous support of `psycopg`
34+
python async_streaming.py psycopg
35+
36+
# Use PostgreSQL protocol, with `asyncpg`
37+
python async_streaming.py asyncpg
38+
39+
# Use with both variants
40+
python async_streaming.py psycopg asyncpg
41+
42+
Bugs
43+
====
44+
45+
When using the `psycopg` driver, the program currently croaks like::
46+
47+
sqlalchemy.exc.InternalError: (psycopg.errors.InternalError_) Cannot find portal: c_10479c0a0_1
48+
49+
"""
50+
import asyncio
51+
import sys
52+
import typing as t
53+
from functools import lru_cache
54+
55+
import sqlalchemy as sa
56+
from sqlalchemy.ext.asyncio import create_async_engine
57+
58+
metadata = sa.MetaData()
59+
table = sa.Table(
60+
"t1",
61+
metadata,
62+
sa.Column("id", sa.Integer, primary_key=True, autoincrement=False),
63+
sa.Column("name", sa.String),
64+
)
65+
66+
67+
class AsynchronousTableStreamingExample:
68+
"""
69+
Demonstrate reading streamed results when using the CrateDB SQLAlchemy
70+
dialect in asynchronous mode with the `psycopg` and `asyncpg` drivers.
71+
72+
- https://docs.sqlalchemy.org/en/20/orm/extensions/asyncio.html#synopsis-core
73+
- https://docs.sqlalchemy.org/en/20/_modules/asyncio/basic.html
74+
"""
75+
76+
def __init__(self, dsn: str):
77+
self.dsn = dsn
78+
79+
@property
80+
@lru_cache
81+
def engine(self):
82+
"""
83+
Provide an SQLAlchemy engine object.
84+
"""
85+
return create_async_engine(self.dsn, echo=True)
86+
87+
async def run(self):
88+
"""
89+
Run the whole recipe.
90+
"""
91+
await self.create_and_insert()
92+
await self.read_buffered()
93+
await self.read_streaming()
94+
95+
async def create_and_insert(self):
96+
"""
97+
Create table schema, completely dropping it upfront, and insert a few records.
98+
"""
99+
# conn is an instance of AsyncConnection
100+
async with self.engine.begin() as conn:
101+
# to support SQLAlchemy DDL methods as well as legacy functions, the
102+
# AsyncConnection.run_sync() awaitable method will pass a "sync"
103+
# version of the AsyncConnection object to any synchronous method,
104+
# where synchronous IO calls will be transparently translated for
105+
# await.
106+
await conn.run_sync(metadata.drop_all, checkfirst=True)
107+
await conn.run_sync(metadata.create_all)
108+
109+
# for normal statement execution, a traditional "await execute()"
110+
# pattern is used.
111+
await conn.execute(
112+
table.insert(),
113+
[{"id": 1, "name": "some name 1"}, {"id": 2, "name": "some name 2"}],
114+
)
115+
116+
# CrateDB specifics to flush/synchronize the write operation.
117+
await conn.execute(sa.text("REFRESH TABLE t1;"))
118+
119+
async def read_buffered(self):
120+
"""
121+
Read data from the database, in buffered mode.
122+
"""
123+
async with self.engine.connect() as conn:
124+
# the default result object is the
125+
# sqlalchemy.engine.Result object
126+
result = await conn.execute(table.select())
127+
128+
# the results are buffered so no await call is necessary
129+
# for this case.
130+
print(result.fetchall())
131+
132+
async def read_streaming(self):
133+
"""
134+
Read data from the database, in streaming mode.
135+
"""
136+
async with self.engine.connect() as conn:
137+
138+
# for a streaming result that buffers only segments of the
139+
# result at time, the AsyncConnection.stream() method is used.
140+
# this returns a sqlalchemy.ext.asyncio.AsyncResult object.
141+
async_result = await conn.stream(table.select())
142+
143+
# this object supports async iteration and awaitable
144+
# versions of methods like .all(), fetchmany(), etc.
145+
async for row in async_result:
146+
print(row)
147+
148+
149+
async def run_example(dsn: str):
150+
example = AsynchronousTableStreamingExample(dsn)
151+
152+
# Run a basic conversation.
153+
# It also includes a catalog inquiry at `table.drop(checkfirst=True)`.
154+
await example.run()
155+
156+
157+
def run_drivers(drivers: t.List[str]):
158+
for driver in drivers:
159+
if driver == "psycopg":
160+
dsn = "crate+psycopg://crate@localhost:5432/doc"
161+
elif driver == "asyncpg":
162+
dsn = "crate+asyncpg://crate@localhost:5432/doc"
163+
else:
164+
raise ValueError(f"Unknown driver: {driver}")
165+
166+
asyncio.run(run_example(dsn))
167+
168+
169+
if __name__ == "__main__":
170+
171+
drivers = sys.argv[1:]
172+
if not drivers:
173+
raise ValueError("Please select driver")
174+
run_drivers(drivers)
Lines changed: 193 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,193 @@
1+
"""
2+
About
3+
=====
4+
5+
Example program to demonstrate how to connect to CrateDB using its SQLAlchemy
6+
dialect, and exercise a few basic examples using the low-level table API, this
7+
time in asynchronous mode.
8+
9+
Both the PostgreSQL drivers based on `psycopg` and `asyncpg` are exercised.
10+
The corresponding SQLAlchemy dialect identifiers are::
11+
12+
# PostgreSQL protocol on port 5432, using `psycopg`
13+
crate+psycopg://crate@localhost:5432/doc
14+
15+
# PostgreSQL protocol on port 5432, using `asyncpg`
16+
crate+asyncpg://crate@localhost:5432/doc
17+
18+
Synopsis
19+
========
20+
::
21+
22+
# Run CrateDB
23+
docker run --rm -it --publish=4200:4200 --publish=5432:5432 crate
24+
25+
# Use PostgreSQL protocol, with asynchronous support of `psycopg`
26+
python async_table.py psycopg
27+
28+
# Use PostgreSQL protocol, with `asyncpg`
29+
python async_table.py asyncpg
30+
31+
# Use with both variants
32+
python async_table.py psycopg asyncpg
33+
34+
"""
35+
import asyncio
36+
import sys
37+
import typing as t
38+
from functools import lru_cache
39+
40+
import sqlalchemy as sa
41+
from sqlalchemy.ext.asyncio import create_async_engine
42+
43+
44+
class AsynchronousTableExample:
45+
"""
46+
Demonstrate the CrateDB SQLAlchemy dialect in asynchronous mode with the `psycopg` and `asyncpg` drivers.
47+
"""
48+
49+
def __init__(self, dsn: str):
50+
self.dsn = dsn
51+
52+
@property
53+
@lru_cache
54+
def engine(self):
55+
"""
56+
Provide an SQLAlchemy engine object.
57+
"""
58+
return create_async_engine(self.dsn, isolation_level="AUTOCOMMIT", echo=True)
59+
60+
@property
61+
@lru_cache
62+
def table(self):
63+
"""
64+
Provide an SQLAlchemy table object.
65+
"""
66+
metadata = sa.MetaData()
67+
return sa.Table(
68+
"testdrive",
69+
metadata,
70+
sa.Column("x", sa.Integer, primary_key=True, autoincrement=False),
71+
sa.Column("y", sa.Integer),
72+
)
73+
74+
async def conn_run_sync(self, func: t.Callable, *args, **kwargs):
75+
"""
76+
To support SQLAlchemy DDL methods as well as legacy functions, the
77+
AsyncConnection.run_sync() awaitable method will pass a "sync"
78+
version of the AsyncConnection object to any synchronous method,
79+
where synchronous IO calls will be transparently translated for
80+
await.
81+
82+
https://docs.sqlalchemy.org/en/20/_modules/asyncio/basic.html
83+
"""
84+
# `conn` is an instance of `AsyncConnection`
85+
async with self.engine.begin() as conn:
86+
return await conn.run_sync(func, *args, **kwargs)
87+
88+
async def run(self):
89+
"""
90+
Run the whole recipe, returning the result from the "read" step.
91+
"""
92+
await self.create()
93+
await self.insert(sync=True)
94+
return await self.read()
95+
96+
async def create(self):
97+
"""
98+
Create table schema, completely dropping it upfront.
99+
"""
100+
await self.conn_run_sync(self.table.drop, checkfirst=True)
101+
await self.conn_run_sync(self.table.create)
102+
103+
async def insert(self, sync: bool = False):
104+
"""
105+
Write data from the database, taking CrateDB-specific `REFRESH TABLE` into account.
106+
"""
107+
async with self.engine.begin() as conn:
108+
stmt = self.table.insert().values(x=1, y=42)
109+
await conn.execute(stmt)
110+
stmt = self.table.insert().values(x=2, y=42)
111+
await conn.execute(stmt)
112+
if sync and self.dsn.startswith("crate"):
113+
await conn.execute(sa.text("REFRESH TABLE testdrive;"))
114+
115+
async def read(self):
116+
"""
117+
Read data from the database.
118+
"""
119+
async with self.engine.begin() as conn:
120+
cursor = await conn.execute(sa.text("SELECT * FROM testdrive;"))
121+
return cursor.fetchall()
122+
123+
async def reflect(self):
124+
"""
125+
Reflect the table schema from the database.
126+
"""
127+
128+
# Debugging.
129+
# self.trace()
130+
131+
def reflect(session):
132+
"""
133+
A function written in "synchronous" style that will be invoked
134+
within the asyncio event loop.
135+
136+
The session object passed is a traditional orm.Session object with
137+
synchronous interface.
138+
139+
https://docs.sqlalchemy.org/en/20/_modules/asyncio/greenlet_orm.html
140+
"""
141+
meta = sa.MetaData()
142+
reflected_table = sa.Table("testdrive", meta, autoload_with=session)
143+
print("Table information:")
144+
print(f"Table: {reflected_table}")
145+
print(f"Columns: {reflected_table.columns}")
146+
print(f"Constraints: {reflected_table.constraints}")
147+
print(f"Primary key: {reflected_table.primary_key}")
148+
149+
return await self.conn_run_sync(reflect)
150+
151+
@staticmethod
152+
def trace():
153+
"""
154+
Trace execution flow through SQLAlchemy.
155+
156+
pip install hunter
157+
"""
158+
from hunter import Q, trace
159+
160+
constraint = Q(module_startswith="sqlalchemy")
161+
trace(constraint)
162+
163+
164+
async def run_example(dsn: str):
165+
example = AsynchronousTableExample(dsn)
166+
167+
# Run a basic conversation.
168+
# It also includes a catalog inquiry at `table.drop(checkfirst=True)`.
169+
result = await example.run()
170+
print(result)
171+
172+
# Reflect the table schema.
173+
await example.reflect()
174+
175+
176+
def run_drivers(drivers: t.List[str]):
177+
for driver in drivers:
178+
if driver == "psycopg":
179+
dsn = "crate+psycopg://crate@localhost:5432/doc"
180+
elif driver == "asyncpg":
181+
dsn = "crate+asyncpg://crate@localhost:5432/doc"
182+
else:
183+
raise ValueError(f"Unknown driver: {driver}")
184+
185+
asyncio.run(run_example(dsn))
186+
187+
188+
if __name__ == "__main__":
189+
190+
drivers = sys.argv[1:]
191+
if not drivers:
192+
raise ValueError("Please select driver")
193+
run_drivers(drivers)
Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,6 @@
11
click<9
22
colorlog<7
3-
crate[sqlalchemy]
43
dask==2023.12.1
54
pandas<2.2
65
sqlalchemy>=2,<2.1
6+
sqlalchemy-cratedb[all] @ git+https://github.com/crate-workbench/sqlalchemy-cratedb@amo/postgresql-async

0 commit comments

Comments
 (0)