Files
sqlalchemy-pgview/docs/guide/alembic.md
2026-02-08 10:09:48 +01:00

7.9 KiB

Alembic Migrations

SQLAlchemy-PGView provides Alembic operations for managing views in database migrations, including autogenerate support for automatic view detection.

Setup

Install with Alembic support:

pip install sqlalchemy-pgview[alembic]

In your env.py, import the alembic module to register comparators and renderers:

# env.py
from alembic import context
from sqlalchemy import engine_from_config
import sqlalchemy_pgview.alembic  # Registers autogenerate support

# Import your models/views
from myapp.models import metadata

Autogenerate Support

When you run alembic revision --autogenerate, Alembic will:

  1. Detect new views: Views in metadata but not in database → generates create_view/create_materialized_view
  2. Detect removed views: Views in database but not in metadata → generates drop_view/drop_materialized_view
  3. Detect changed views: Views with different definitions → generates drop + create
# Generate migration with view changes
alembic revision --autogenerate -m "add user stats view"

Register views with metadata to enable detection:

from sqlalchemy import MetaData, Table, Column, Integer, String, select
from sqlalchemy_pgview import View, MaterializedView

metadata = MetaData()

users = Table("users", metadata, ...)

# These views will be detected by autogenerate
active_users = View(
    "active_users",
    select(users.c.id, users.c.name).where(users.c.is_active == True),
    metadata=metadata,
)

user_stats = MaterializedView(
    "user_stats",
    select(users.c.id, users.c.name),
    metadata=metadata,
)

Generated migration example:

"""add user stats view

Revision ID: abc123
"""
from alembic import op
import sqlalchemy_pgview.alembic

def upgrade():
    op.create_view(
        "active_users",
        "SELECT users.id, users.name FROM users WHERE users.is_active = true"
    )
    op.create_materialized_view(
        "user_stats",
        "SELECT users.id, users.name FROM users",
        with_data=True
    )

def downgrade():
    op.drop_materialized_view("user_stats")
    op.drop_view("active_users")

Creating Views

def upgrade():
    # Regular view
    op.create_view(
        "active_users",
        """
        SELECT id, name, email
        FROM users
        WHERE is_active = true
        """,
    )

    # With schema
    op.create_view(
        "user_metrics",
        """
        SELECT
            user_id,
            COUNT(*) as order_count,
            SUM(total) as total_spent
        FROM orders
        GROUP BY user_id
        """,
        schema="analytics",
    )

    # CREATE OR REPLACE (won't fail if exists)
    op.create_view(
        "user_stats",
        "SELECT id, name, created_at FROM users",
        or_replace=True,
    )

def downgrade():
    op.drop_view("user_stats")
    op.drop_view("user_metrics", schema="analytics")
    op.drop_view("active_users")

Creating Materialized Views

def upgrade():
    # With data populated immediately
    op.create_materialized_view(
        "monthly_revenue",
        """
        SELECT
            date_trunc('month', created_at) as month,
            SUM(total) as revenue
        FROM orders
        GROUP BY date_trunc('month', created_at)
        """,
        with_data=True,
    )

    # Without initial data (populate later)
    op.create_materialized_view(
        "large_summary",
        "SELECT ...",
        with_data=False,
    )

def downgrade():
    op.drop_materialized_view("large_summary")
    op.drop_materialized_view("monthly_revenue")

Dropping Views

def upgrade():
    # Regular view
    op.drop_view("old_view")

    # With options
    op.drop_view("another_view", if_exists=True, cascade=True)

    # Materialized view
    op.drop_materialized_view("old_mv", if_exists=True, cascade=True)

Refreshing Materialized Views

Use in data migrations:

def upgrade():
    # After data changes, refresh the view
    op.refresh_materialized_view("monthly_revenue")

    # Concurrent refresh (requires unique index)
    op.refresh_materialized_view("monthly_revenue", concurrently=True)

Modifying a View

Views can't be altered - drop and recreate:

def upgrade():
    op.drop_view("user_stats")
    op.create_view(
        "user_stats",
        """
        SELECT
            u.id,
            u.name,
            u.email,  -- Added column
            COUNT(o.id) as order_count,
            COALESCE(SUM(o.total), 0) as total_spent
        FROM users u
        LEFT JOIN orders o ON u.id = o.user_id
        GROUP BY u.id, u.name, u.email
        """,
    )

def downgrade():
    op.drop_view("user_stats")
    op.create_view(
        "user_stats",
        """
        SELECT
            u.id,
            u.name,
            COUNT(o.id) as order_count,
            COALESCE(SUM(o.total), 0) as total_spent
        FROM users u
        LEFT JOIN orders o ON u.id = o.user_id
        GROUP BY u.id, u.name
        """,
    )

!!! tip "Use OR REPLACE When Possible" If you're only changing the query (not column names/types), use or_replace=True:

```python
def upgrade():
    op.create_view(
        "user_stats",
        "SELECT ... (new query)",
        or_replace=True,
    )
```

Dependent Views

Drop dependents first, recreate in order:

def upgrade():
    # Drop in reverse dependency order
    op.drop_view("derived_view", if_exists=True)
    op.drop_view("base_view", if_exists=True)

    # Recreate base view with changes
    op.create_view("base_view", "SELECT ...")

    # Recreate derived view
    op.create_view("derived_view", "SELECT * FROM base_view WHERE ...")

def downgrade():
    op.drop_view("derived_view")
    op.drop_view("base_view")
    op.create_view("base_view", "SELECT ... (old query)")
    op.create_view("derived_view", "SELECT ... (old query)")

Converting Table to Materialized View

def upgrade():
    # Create materialized view from table data
    op.create_materialized_view(
        "summary_mv",
        """
        SELECT
            category,
            COUNT(*) as count,
            SUM(amount) as total
        FROM transactions
        GROUP BY category
        """,
        with_data=True,
    )

    # Optionally drop the old summary table
    op.drop_table("summary_table")

def downgrade():
    # Recreate table
    op.create_table(
        "summary_table",
        sa.Column("category", sa.String(50)),
        sa.Column("count", sa.Integer),
        sa.Column("total", sa.Numeric(10, 2)),
    )

    # Populate from materialized view
    op.execute("""
        INSERT INTO summary_table
        SELECT * FROM summary_mv
    """)

    op.drop_materialized_view("summary_mv")

Complete Example

"""Add analytics views

Revision ID: abc123
"""
from alembic import op
import sqlalchemy_pgview.alembic

revision = 'abc123'
down_revision = 'xyz789'

def upgrade():
    # Create schema
    op.execute("CREATE SCHEMA IF NOT EXISTS analytics")

    # Regular view for real-time queries
    op.create_view(
        "active_orders",
        """
        SELECT *
        FROM orders
        WHERE status = 'pending'
        """,
        schema="analytics",
    )

    # Materialized view for reports
    op.create_materialized_view(
        "daily_revenue",
        """
        SELECT
            date_trunc('day', created_at) as day,
            COUNT(*) as orders,
            SUM(total) as revenue
        FROM orders
        WHERE status = 'completed'
        GROUP BY date_trunc('day', created_at)
        """,
        schema="analytics",
        with_data=True,
    )

    # Create index for concurrent refresh
    op.execute("""
        CREATE UNIQUE INDEX idx_daily_revenue_day
        ON analytics.daily_revenue (day)
    """)

def downgrade():
    op.drop_materialized_view("daily_revenue", schema="analytics")
    op.drop_view("active_orders", schema="analytics")
    op.execute("DROP SCHEMA IF EXISTS analytics")