"""Initial PostgreSQL/PostGIS schema""" from __future__ import annotations import sqlalchemy as sa from alembic import op from geoalchemy2.types import Geometry from sqlalchemy.dialects import postgresql # revision identifiers, used by Alembic. revision = "20251011_01" down_revision = None branch_labels = None depends_on = None def upgrade() -> None: op.execute("CREATE EXTENSION IF NOT EXISTS postgis") op.execute("CREATE EXTENSION IF NOT EXISTS pgcrypto") op.create_table( "users", sa.Column( "id", postgresql.UUID(as_uuid=True), primary_key=True, server_default=sa.text("gen_random_uuid()"), ), sa.Column("username", sa.String(length=64), nullable=False, unique=True), sa.Column("email", sa.String(length=255), nullable=True, unique=True), sa.Column("full_name", sa.String(length=128), nullable=True), sa.Column("password_hash", sa.String(length=256), nullable=False), sa.Column( "role", sa.String(length=32), nullable=False, server_default="player" ), sa.Column("preferences", sa.Text(), nullable=True), sa.Column( "created_at", sa.DateTime(timezone=True), server_default=sa.text("timezone('utc', now())"), nullable=False, ), sa.Column( "updated_at", sa.DateTime(timezone=True), server_default=sa.text("timezone('utc', now())"), nullable=False, ), ) op.create_table( "stations", sa.Column( "id", postgresql.UUID(as_uuid=True), primary_key=True, server_default=sa.text("gen_random_uuid()"), ), sa.Column("osm_id", sa.String(length=32), nullable=True), sa.Column("name", sa.String(length=128), nullable=False), sa.Column("code", sa.String(length=16), nullable=True), sa.Column( "location", Geometry(geometry_type="POINT", srid=4326), nullable=False ), sa.Column("elevation_m", sa.Float(), nullable=True), sa.Column( "is_active", sa.Boolean(), nullable=False, server_default=sa.text("true") ), sa.Column( "created_at", sa.DateTime(timezone=True), server_default=sa.text("timezone('utc', now())"), nullable=False, ), sa.Column( "updated_at", sa.DateTime(timezone=True), server_default=sa.text("timezone('utc', now())"), nullable=False, ), ) op.create_index( "ix_stations_location", "stations", ["location"], postgresql_using="gist" ) op.create_table( "tracks", sa.Column( "id", postgresql.UUID(as_uuid=True), primary_key=True, server_default=sa.text("gen_random_uuid()"), ), sa.Column("name", sa.String(length=128), nullable=True), sa.Column("start_station_id", postgresql.UUID(as_uuid=True), nullable=False), sa.Column("end_station_id", postgresql.UUID(as_uuid=True), nullable=False), sa.Column("length_meters", sa.Numeric(10, 2), nullable=True), sa.Column("max_speed_kph", sa.Integer(), nullable=True), sa.Column( "is_bidirectional", sa.Boolean(), nullable=False, server_default=sa.text("true"), ), sa.Column( "status", sa.String(length=32), nullable=False, server_default="planned" ), sa.Column( "track_geometry", Geometry(geometry_type="LINESTRING", srid=4326), nullable=False, ), sa.Column( "created_at", sa.DateTime(timezone=True), server_default=sa.text("timezone('utc', now())"), nullable=False, ), sa.Column( "updated_at", sa.DateTime(timezone=True), server_default=sa.text("timezone('utc', now())"), nullable=False, ), sa.ForeignKeyConstraint( ["start_station_id"], ["stations.id"], ondelete="RESTRICT" ), sa.ForeignKeyConstraint( ["end_station_id"], ["stations.id"], ondelete="RESTRICT" ), sa.UniqueConstraint( "start_station_id", "end_station_id", name="uq_tracks_station_pair" ), ) op.create_index( "ix_tracks_geometry", "tracks", ["track_geometry"], postgresql_using="gist" ) op.create_table( "trains", sa.Column( "id", postgresql.UUID(as_uuid=True), primary_key=True, server_default=sa.text("gen_random_uuid()"), ), sa.Column("designation", sa.String(length=64), nullable=False, unique=True), sa.Column("operator_id", postgresql.UUID(as_uuid=True), nullable=True), sa.Column("home_station_id", postgresql.UUID(as_uuid=True), nullable=True), sa.Column("capacity", sa.Integer(), nullable=False), sa.Column("max_speed_kph", sa.Integer(), nullable=False), sa.Column("consist", sa.Text(), nullable=True), sa.Column( "created_at", sa.DateTime(timezone=True), server_default=sa.text("timezone('utc', now())"), nullable=False, ), sa.Column( "updated_at", sa.DateTime(timezone=True), server_default=sa.text("timezone('utc', now())"), nullable=False, ), sa.ForeignKeyConstraint(["operator_id"], ["users.id"], ondelete="SET NULL"), sa.ForeignKeyConstraint( ["home_station_id"], ["stations.id"], ondelete="SET NULL" ), ) op.create_table( "train_schedules", sa.Column( "id", postgresql.UUID(as_uuid=True), primary_key=True, server_default=sa.text("gen_random_uuid()"), ), sa.Column("train_id", postgresql.UUID(as_uuid=True), nullable=False), sa.Column("sequence_index", sa.Integer(), nullable=False), sa.Column("station_id", postgresql.UUID(as_uuid=True), nullable=False), sa.Column("scheduled_arrival", sa.DateTime(timezone=True), nullable=True), sa.Column("scheduled_departure", sa.DateTime(timezone=True), nullable=True), sa.Column("dwell_seconds", sa.Integer(), nullable=True), sa.Column( "created_at", sa.DateTime(timezone=True), server_default=sa.text("timezone('utc', now())"), nullable=False, ), sa.Column( "updated_at", sa.DateTime(timezone=True), server_default=sa.text("timezone('utc', now())"), nullable=False, ), sa.ForeignKeyConstraint(["train_id"], ["trains.id"], ondelete="CASCADE"), sa.ForeignKeyConstraint(["station_id"], ["stations.id"], ondelete="CASCADE"), sa.UniqueConstraint( "train_id", "sequence_index", name="uq_train_schedule_sequence" ), ) def downgrade() -> None: op.drop_table("train_schedules") op.drop_table("trains") op.drop_index("ix_tracks_geometry", table_name="tracks") op.drop_table("tracks") op.drop_index("ix_stations_location", table_name="stations") op.drop_table("stations") op.drop_table("users") op.execute("DROP EXTENSION IF EXISTS pgcrypto") op.execute("DROP EXTENSION IF EXISTS postgis")