mirror of
https://github.com/d3vyce/sqlalchemy-pgview.git
synced 2026-03-02 00:30:47 +01:00
220 lines
5.4 KiB
Markdown
220 lines
5.4 KiB
Markdown
# Async Support
|
|
|
|
SQLAlchemy-PGView works with SQLAlchemy's async engine using `asyncpg`.
|
|
|
|
## Setup
|
|
|
|
Install asyncpg:
|
|
|
|
```bash
|
|
pip install asyncpg
|
|
```
|
|
|
|
Create an async engine:
|
|
|
|
```python
|
|
from sqlalchemy.ext.asyncio import create_async_engine
|
|
|
|
engine = create_async_engine("postgresql+asyncpg://user:pass@localhost/db")
|
|
```
|
|
|
|
## Creating Views (Async)
|
|
|
|
```python
|
|
from sqlalchemy import select, func
|
|
from sqlalchemy_pgview import View, CreateView, DropView
|
|
|
|
user_stats = View(
|
|
"user_stats",
|
|
select(
|
|
users.c.id,
|
|
users.c.name,
|
|
func.count(orders.c.id).label("order_count"),
|
|
)
|
|
.join(orders)
|
|
.group_by(users.c.id, users.c.name),
|
|
)
|
|
|
|
async with engine.begin() as conn:
|
|
# Create view
|
|
await conn.execute(CreateView(user_stats, or_replace=True))
|
|
|
|
# Query view
|
|
result = await conn.execute(select(user_stats.as_table()))
|
|
rows = result.fetchall()
|
|
|
|
# Drop view
|
|
await conn.execute(DropView(user_stats, if_exists=True))
|
|
```
|
|
|
|
## Materialized Views (Async)
|
|
|
|
```python
|
|
from sqlalchemy_pgview import (
|
|
MaterializedView,
|
|
CreateMaterializedView,
|
|
RefreshMaterializedView,
|
|
DropMaterializedView,
|
|
)
|
|
|
|
monthly_stats = MaterializedView(
|
|
"monthly_stats",
|
|
select(
|
|
func.date_trunc('month', orders.c.created_at).label("month"),
|
|
func.sum(orders.c.total).label("revenue"),
|
|
).group_by(func.date_trunc('month', orders.c.created_at)),
|
|
with_data=True,
|
|
)
|
|
|
|
async with engine.begin() as conn:
|
|
# Create
|
|
await conn.execute(CreateMaterializedView(monthly_stats))
|
|
|
|
# Query
|
|
result = await conn.execute(select(monthly_stats.as_table()))
|
|
rows = result.fetchall()
|
|
|
|
# Refresh
|
|
await conn.execute(RefreshMaterializedView(monthly_stats))
|
|
|
|
# Drop
|
|
await conn.execute(DropMaterializedView(monthly_stats, if_exists=True))
|
|
```
|
|
|
|
## Refreshing with .refresh() Method
|
|
|
|
The `.refresh()` method is synchronous. Use `run_sync` to call it from async code:
|
|
|
|
```python
|
|
async with engine.begin() as conn:
|
|
# Use run_sync for the synchronous refresh method
|
|
def refresh_sync(sync_conn):
|
|
monthly_stats.refresh(sync_conn)
|
|
|
|
await conn.run_sync(refresh_sync)
|
|
```
|
|
|
|
Or use the DDL directly:
|
|
|
|
```python
|
|
async with engine.begin() as conn:
|
|
await conn.execute(RefreshMaterializedView(monthly_stats, concurrently=True))
|
|
```
|
|
|
|
!!! tip "Prefer DDL Classes for Async"
|
|
For async code, prefer using `RefreshMaterializedView` DDL class over the `.refresh()` method to avoid `run_sync` overhead.
|
|
|
|
## Dependency Functions (Async)
|
|
|
|
The dependency tracking functions are synchronous. Use `run_sync`:
|
|
|
|
```python
|
|
from sqlalchemy_pgview import get_all_views, get_view_definition
|
|
|
|
async with engine.connect() as conn:
|
|
# Get all views
|
|
views = await conn.run_sync(lambda c: get_all_views(c))
|
|
|
|
for view in views:
|
|
print(f"{view.fullname}: {'MV' if view.is_materialized else 'V'}")
|
|
|
|
# Get view definition
|
|
definition = await conn.run_sync(
|
|
lambda c: get_view_definition(c, "user_stats")
|
|
)
|
|
```
|
|
|
|
## Sync vs Async Operations
|
|
|
|
| Operation | Sync | Async |
|
|
|-----------|------|-------|
|
|
| DDL (CREATE/DROP) | Direct | Direct |
|
|
| Queries | Direct | Direct |
|
|
| `.refresh()` method | Direct | Use `run_sync` |
|
|
| Dependency functions | Direct | Use `run_sync` |
|
|
|
|
## Complete Example
|
|
|
|
```python
|
|
import asyncio
|
|
from decimal import Decimal
|
|
|
|
from sqlalchemy import Column, Integer, String, Numeric, ForeignKey, MetaData, Table, select, func
|
|
from sqlalchemy.ext.asyncio import create_async_engine
|
|
from sqlalchemy_pgview import (
|
|
View,
|
|
MaterializedView,
|
|
CreateView,
|
|
CreateMaterializedView,
|
|
RefreshMaterializedView,
|
|
DropView,
|
|
DropMaterializedView,
|
|
)
|
|
|
|
|
|
async def main():
|
|
engine = create_async_engine("postgresql+asyncpg://user:pass@localhost/db")
|
|
metadata = MetaData()
|
|
|
|
users = Table(
|
|
"users", metadata,
|
|
Column("id", Integer, primary_key=True),
|
|
Column("name", String(100)),
|
|
)
|
|
|
|
orders = Table(
|
|
"orders", metadata,
|
|
Column("id", Integer, primary_key=True),
|
|
Column("user_id", Integer, ForeignKey("users.id")),
|
|
Column("total", Numeric(10, 2)),
|
|
)
|
|
|
|
# Create tables
|
|
async with engine.begin() as conn:
|
|
await conn.run_sync(metadata.create_all)
|
|
|
|
# Define views
|
|
user_summary = View(
|
|
"user_summary",
|
|
select(
|
|
users.c.id,
|
|
users.c.name,
|
|
func.count(orders.c.id).label("order_count"),
|
|
)
|
|
.select_from(users.outerjoin(orders))
|
|
.group_by(users.c.id, users.c.name),
|
|
)
|
|
|
|
revenue_mv = MaterializedView(
|
|
"revenue_summary",
|
|
select(func.sum(orders.c.total).label("total_revenue")),
|
|
with_data=True,
|
|
)
|
|
|
|
async with engine.begin() as conn:
|
|
# Create views
|
|
await conn.execute(CreateView(user_summary, or_replace=True))
|
|
await conn.execute(CreateMaterializedView(revenue_mv))
|
|
|
|
# Query regular view (always current)
|
|
result = await conn.execute(select(user_summary.as_table()))
|
|
print("User Summary:", result.fetchall())
|
|
|
|
# Query materialized view
|
|
result = await conn.execute(select(revenue_mv.as_table()))
|
|
print("Revenue:", result.fetchone())
|
|
|
|
# Refresh materialized view
|
|
await conn.execute(RefreshMaterializedView(revenue_mv))
|
|
|
|
# Cleanup
|
|
await conn.execute(DropMaterializedView(revenue_mv, if_exists=True))
|
|
await conn.execute(DropView(user_summary, if_exists=True))
|
|
|
|
await engine.dispose()
|
|
|
|
|
|
if __name__ == "__main__":
|
|
asyncio.run(main())
|
|
```
|