"""Initial schema setup Revision ID: 0001_initial_schema Revises: Create Date: YYYY-MM-DD HH:MM:SS.ffffff """ from typing import Sequence, Union from alembic import op import sqlalchemy as sa from sqlalchemy.dialects import postgresql # revision identifiers, used by Alembic. revision: str = '0001_initial_schema' down_revision: Union[str, None] = None branch_labels: Union[str, Sequence[str], None] = None depends_on: Union[str, Sequence[str], None] = None user_role_enum = postgresql.ENUM('owner', 'member', name='userroleenum', create_type=False) split_type_enum = postgresql.ENUM('EQUAL', 'EXACT_AMOUNTS', 'PERCENTAGE', 'SHARES', 'ITEM_BASED', name='splittypeenum', create_type=False) expense_split_status_enum = postgresql.ENUM('unpaid', 'partially_paid', 'paid', name='expensesplitstatusenum', create_type=False) expense_overall_status_enum = postgresql.ENUM('unpaid', 'partially_paid', 'paid', name='expenseoverallstatusenum', create_type=False) recurrence_type_enum = postgresql.ENUM('DAILY', 'WEEKLY', 'MONTHLY', 'YEARLY', name='recurrencetypeenum', create_type=False) chore_frequency_enum = postgresql.ENUM('one_time', 'daily', 'weekly', 'monthly', 'custom', name='chorefrequencyenum', create_type=False) chore_type_enum = postgresql.ENUM('personal', 'group', name='choretypeenum', create_type=False) def upgrade(context) -> None: def create_enums(): user_role_enum.create(op.get_bind(), checkfirst=True) split_type_enum.create(op.get_bind(), checkfirst=True) expense_split_status_enum.create(op.get_bind(), checkfirst=True) expense_overall_status_enum.create(op.get_bind(), checkfirst=True) recurrence_type_enum.create(op.get_bind(), checkfirst=True) chore_frequency_enum.create(op.get_bind(), checkfirst=True) chore_type_enum.create(op.get_bind(), checkfirst=True) create_enums() op.create_table('users', sa.Column('id', sa.Integer(), nullable=False), sa.Column('email', sa.String(), nullable=False), sa.Column('hashed_password', sa.String(), nullable=False), sa.Column('name', sa.String(), nullable=True), sa.Column('is_active', sa.Boolean(), server_default=sa.text('true'), nullable=False), sa.Column('is_superuser', sa.Boolean(), server_default=sa.text('false'), nullable=False), sa.Column('is_verified', sa.Boolean(), server_default=sa.text('false'), nullable=False), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_users_email'), 'users', ['email'], unique=True) op.create_index(op.f('ix_users_id'), 'users', ['id'], unique=False) op.create_index(op.f('ix_users_name'), 'users', ['name'], unique=False) op.create_table('groups', sa.Column('id', sa.Integer(), nullable=False), sa.Column('name', sa.String(), nullable=False), sa.Column('created_by_id', sa.Integer(), nullable=False), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.ForeignKeyConstraint(['created_by_id'], ['users.id'], ), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_groups_id'), 'groups', ['id'], unique=False) op.create_index(op.f('ix_groups_name'), 'groups', ['name'], unique=False) op.create_table('user_groups', sa.Column('id', sa.Integer(), nullable=False), sa.Column('user_id', sa.Integer(), nullable=False), sa.Column('group_id', sa.Integer(), nullable=False), sa.Column('role', user_role_enum, nullable=False), sa.Column('joined_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.ForeignKeyConstraint(['group_id'], ['groups.id'], ondelete='CASCADE'), sa.ForeignKeyConstraint(['user_id'], ['users.id'], ondelete='CASCADE'), sa.PrimaryKeyConstraint('id'), sa.UniqueConstraint('user_id', 'group_id', name='uq_user_group') ) op.create_index(op.f('ix_user_groups_id'), 'user_groups', ['id'], unique=False) op.create_table('invites', sa.Column('id', sa.Integer(), nullable=False), sa.Column('code', sa.String(), nullable=False), sa.Column('group_id', sa.Integer(), nullable=False), sa.Column('created_by_id', sa.Integer(), nullable=False), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('expires_at', sa.DateTime(timezone=True), nullable=False), sa.Column('is_active', sa.Boolean(), server_default=sa.text('true'), nullable=False), sa.ForeignKeyConstraint(['created_by_id'], ['users.id'], ), sa.ForeignKeyConstraint(['group_id'], ['groups.id'], ondelete='CASCADE'), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_invites_code'), 'invites', ['code'], unique=False) op.create_index('ix_invites_active_code', 'invites', ['code'], unique=True, postgresql_where=sa.text('is_active = true')) op.create_index(op.f('ix_invites_id'), 'invites', ['id'], unique=False) op.create_table('lists', sa.Column('id', sa.Integer(), nullable=False), sa.Column('name', sa.String(), nullable=False), sa.Column('description', sa.Text(), nullable=True), sa.Column('created_by_id', sa.Integer(), nullable=False), sa.Column('group_id', sa.Integer(), nullable=True), sa.Column('is_complete', sa.Boolean(), server_default=sa.text('false'), nullable=False), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('updated_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('version', sa.Integer(), server_default='1', nullable=False), sa.ForeignKeyConstraint(['created_by_id'], ['users.id'], ), sa.ForeignKeyConstraint(['group_id'], ['groups.id'], ), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_lists_id'), 'lists', ['id'], unique=False) op.create_index(op.f('ix_lists_name'), 'lists', ['name'], unique=False) op.create_table('items', sa.Column('id', sa.Integer(), nullable=False), sa.Column('list_id', sa.Integer(), nullable=False), sa.Column('name', sa.String(), nullable=False), sa.Column('quantity', sa.String(), nullable=True), sa.Column('is_complete', sa.Boolean(), server_default=sa.text('false'), nullable=False), sa.Column('price', sa.Numeric(precision=10, scale=2), nullable=True), sa.Column('added_by_id', sa.Integer(), nullable=False), sa.Column('completed_by_id', sa.Integer(), nullable=True), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('updated_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('version', sa.Integer(), server_default='1', nullable=False), sa.ForeignKeyConstraint(['added_by_id'], ['users.id'], ), sa.ForeignKeyConstraint(['completed_by_id'], ['users.id'], ), sa.ForeignKeyConstraint(['list_id'], ['lists.id'], ondelete='CASCADE'), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_items_id'), 'items', ['id'], unique=False) op.create_index(op.f('ix_items_name'), 'items', ['name'], unique=False) op.create_table('recurrence_patterns', sa.Column('id', sa.Integer(), nullable=False), sa.Column('type', recurrence_type_enum, nullable=False), sa.Column('interval', sa.Integer(), server_default='1', nullable=False), sa.Column('days_of_week', sa.String(), nullable=True), sa.Column('end_date', sa.DateTime(timezone=True), nullable=True), sa.Column('max_occurrences', sa.Integer(), nullable=True), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('updated_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_recurrence_patterns_id'), 'recurrence_patterns', ['id'], unique=False) op.create_table('expenses', sa.Column('id', sa.Integer(), nullable=False), sa.Column('description', sa.String(), nullable=False), sa.Column('total_amount', sa.Numeric(precision=10, scale=2), nullable=False), sa.Column('currency', sa.String(), server_default='USD', nullable=False), sa.Column('expense_date', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('split_type', split_type_enum, nullable=False), sa.Column('list_id', sa.Integer(), nullable=True), sa.Column('group_id', sa.Integer(), nullable=True), sa.Column('item_id', sa.Integer(), nullable=True), sa.Column('paid_by_user_id', sa.Integer(), nullable=False), sa.Column('created_by_user_id', sa.Integer(), nullable=False), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('updated_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('version', sa.Integer(), server_default='1', nullable=False), sa.Column('overall_settlement_status', expense_overall_status_enum, server_default='unpaid', nullable=False), sa.Column('is_recurring', sa.Boolean(), server_default=sa.text('false'), nullable=False), sa.Column('recurrence_pattern_id', sa.Integer(), nullable=True), sa.Column('next_occurrence', sa.DateTime(timezone=True), nullable=True), sa.Column('parent_expense_id', sa.Integer(), nullable=True), sa.Column('last_occurrence', sa.DateTime(timezone=True), nullable=True), sa.CheckConstraint('(item_id IS NOT NULL) OR (list_id IS NOT NULL) OR (group_id IS NOT NULL)', name='chk_expense_context'), sa.ForeignKeyConstraint(['created_by_user_id'], ['users.id'], ), sa.ForeignKeyConstraint(['group_id'], ['groups.id'], ), sa.ForeignKeyConstraint(['item_id'], ['items.id'], ), sa.ForeignKeyConstraint(['list_id'], ['lists.id'], ), sa.ForeignKeyConstraint(['paid_by_user_id'], ['users.id'], ), sa.ForeignKeyConstraint(['parent_expense_id'], ['expenses.id'], ), sa.ForeignKeyConstraint(['recurrence_pattern_id'], ['recurrence_patterns.id'], ), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_expenses_created_by_user_id'), 'expenses', ['created_by_user_id'], unique=False) op.create_index(op.f('ix_expenses_group_id'), 'expenses', ['group_id'], unique=False) op.create_index(op.f('ix_expenses_id'), 'expenses', ['id'], unique=False) op.create_index(op.f('ix_expenses_list_id'), 'expenses', ['list_id'], unique=False) op.create_index(op.f('ix_expenses_paid_by_user_id'), 'expenses', ['paid_by_user_id'], unique=False) op.create_index('ix_expenses_recurring_next_occurrence', 'expenses', ['is_recurring', 'next_occurrence'], unique=False, postgresql_where=sa.text('is_recurring = true')) op.create_table('expense_splits', sa.Column('id', sa.Integer(), nullable=False), sa.Column('expense_id', sa.Integer(), nullable=False), sa.Column('user_id', sa.Integer(), nullable=False), sa.Column('owed_amount', sa.Numeric(precision=10, scale=2), nullable=False), sa.Column('share_percentage', sa.Numeric(precision=5, scale=2), nullable=True), sa.Column('share_units', sa.Integer(), nullable=True), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('updated_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('status', expense_split_status_enum, server_default='unpaid', nullable=False), sa.Column('paid_at', sa.DateTime(timezone=True), nullable=True), sa.ForeignKeyConstraint(['expense_id'], ['expenses.id'], ondelete='CASCADE'), sa.ForeignKeyConstraint(['user_id'], ['users.id'], ), sa.PrimaryKeyConstraint('id'), sa.UniqueConstraint('expense_id', 'user_id', name='uq_expense_user_split') ) op.create_index(op.f('ix_expense_splits_id'), 'expense_splits', ['id'], unique=False) op.create_index(op.f('ix_expense_splits_user_id'), 'expense_splits', ['user_id'], unique=False) op.create_table('settlements', sa.Column('id', sa.Integer(), nullable=False), sa.Column('group_id', sa.Integer(), nullable=False), sa.Column('paid_by_user_id', sa.Integer(), nullable=False), sa.Column('paid_to_user_id', sa.Integer(), nullable=False), sa.Column('amount', sa.Numeric(precision=10, scale=2), nullable=False), sa.Column('settlement_date', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('description', sa.Text(), nullable=True), sa.Column('created_by_user_id', sa.Integer(), nullable=False), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('updated_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('version', sa.Integer(), server_default='1', nullable=False), sa.CheckConstraint('paid_by_user_id != paid_to_user_id', name='chk_settlement_different_users'), sa.ForeignKeyConstraint(['created_by_user_id'], ['users.id'], ), sa.ForeignKeyConstraint(['group_id'], ['groups.id'], ), sa.ForeignKeyConstraint(['paid_by_user_id'], ['users.id'], ), sa.ForeignKeyConstraint(['paid_to_user_id'], ['users.id'], ), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_settlements_created_by_user_id'), 'settlements', ['created_by_user_id'], unique=False) op.create_index(op.f('ix_settlements_group_id'), 'settlements', ['group_id'], unique=False) op.create_index(op.f('ix_settlements_id'), 'settlements', ['id'], unique=False) op.create_index(op.f('ix_settlements_paid_by_user_id'), 'settlements', ['paid_by_user_id'], unique=False) op.create_index(op.f('ix_settlements_paid_to_user_id'), 'settlements', ['paid_to_user_id'], unique=False) op.create_table('settlement_activities', sa.Column('id', sa.Integer(), nullable=False), sa.Column('expense_split_id', sa.Integer(), nullable=False), sa.Column('paid_by_user_id', sa.Integer(), nullable=False), sa.Column('paid_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('amount_paid', sa.Numeric(precision=10, scale=2), nullable=False), sa.Column('created_by_user_id', sa.Integer(), nullable=False), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('updated_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.ForeignKeyConstraint(['created_by_user_id'], ['users.id'], ), sa.ForeignKeyConstraint(['expense_split_id'], ['expense_splits.id'], ), sa.ForeignKeyConstraint(['paid_by_user_id'], ['users.id'], ), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_settlement_activity_created_by_user_id'), 'settlement_activities', ['created_by_user_id'], unique=False) op.create_index(op.f('ix_settlement_activity_expense_split_id'), 'settlement_activities', ['expense_split_id'], unique=False) op.create_index(op.f('ix_settlement_activity_paid_by_user_id'), 'settlement_activities', ['paid_by_user_id'], unique=False) op.create_table('chores', sa.Column('id', sa.Integer(), nullable=False), sa.Column('type', chore_type_enum, nullable=False), sa.Column('group_id', sa.Integer(), nullable=True), sa.Column('name', sa.String(), nullable=False), sa.Column('description', sa.Text(), nullable=True), sa.Column('created_by_id', sa.Integer(), nullable=False), sa.Column('frequency', chore_frequency_enum, nullable=False), sa.Column('custom_interval_days', sa.Integer(), nullable=True), sa.Column('next_due_date', sa.Date(), nullable=False), sa.Column('last_completed_at', sa.DateTime(timezone=True), nullable=True), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('updated_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.ForeignKeyConstraint(['created_by_id'], ['users.id'], ), sa.ForeignKeyConstraint(['group_id'], ['groups.id'], ondelete='CASCADE'), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_chores_created_by_id'), 'chores', ['created_by_id'], unique=False) op.create_index(op.f('ix_chores_group_id'), 'chores', ['group_id'], unique=False) op.create_index(op.f('ix_chores_id'), 'chores', ['id'], unique=False) op.create_index(op.f('ix_chores_name'), 'chores', ['name'], unique=False) op.create_table('chore_assignments', sa.Column('id', sa.Integer(), nullable=False), sa.Column('chore_id', sa.Integer(), nullable=False), sa.Column('assigned_to_user_id', sa.Integer(), nullable=False), sa.Column('due_date', sa.Date(), nullable=False), sa.Column('is_complete', sa.Boolean(), server_default=sa.text('false'), nullable=False), sa.Column('completed_at', sa.DateTime(timezone=True), nullable=True), sa.Column('created_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.Column('updated_at', sa.DateTime(timezone=True), server_default=sa.text('now()'), nullable=False), sa.ForeignKeyConstraint(['assigned_to_user_id'], ['users.id'], ondelete='CASCADE'), sa.ForeignKeyConstraint(['chore_id'], ['chores.id'], ondelete='CASCADE'), sa.PrimaryKeyConstraint('id') ) op.create_index(op.f('ix_chore_assignments_assigned_to_user_id'), 'chore_assignments', ['assigned_to_user_id'], unique=False) op.create_index(op.f('ix_chore_assignments_chore_id'), 'chore_assignments', ['chore_id'], unique=False) op.create_index(op.f('ix_chore_assignments_id'), 'chore_assignments', ['id'], unique=False) def downgrade() -> None: op.drop_table('chore_assignments') op.drop_index(op.f('ix_chores_name'), table_name='chores') op.drop_index(op.f('ix_chores_id'), table_name='chores') op.drop_index(op.f('ix_chores_group_id'), table_name='chores') op.drop_index(op.f('ix_chores_created_by_id'), table_name='chores') op.drop_table('chores') op.drop_index(op.f('ix_settlement_activity_paid_by_user_id'), table_name='settlement_activities') op.drop_index(op.f('ix_settlement_activity_expense_split_id'), table_name='settlement_activities') op.drop_index(op.f('ix_settlement_activity_created_by_user_id'), table_name='settlement_activities') op.drop_table('settlement_activities') op.drop_index(op.f('ix_settlements_paid_to_user_id'), table_name='settlements') op.drop_index(op.f('ix_settlements_paid_by_user_id'), table_name='settlements') op.drop_index(op.f('ix_settlements_id'), table_name='settlements') op.drop_index(op.f('ix_settlements_group_id'), table_name='settlements') op.drop_index(op.f('ix_settlements_created_by_user_id'), table_name='settlements') op.drop_table('settlements') op.drop_index(op.f('ix_expense_splits_user_id'), table_name='expense_splits') op.drop_index(op.f('ix_expense_splits_id'), table_name='expense_splits') op.drop_table('expense_splits') op.drop_index('ix_expenses_recurring_next_occurrence', table_name='expenses') op.drop_index(op.f('ix_expenses_paid_by_user_id'), table_name='expenses') op.drop_index(op.f('ix_expenses_list_id'), table_name='expenses') op.drop_index(op.f('ix_expenses_id'), table_name='expenses') op.drop_index(op.f('ix_expenses_group_id'), table_name='expenses') op.drop_index(op.f('ix_expenses_created_by_user_id'), table_name='expenses') op.drop_table('expenses') op.drop_index(op.f('ix_recurrence_patterns_id'), table_name='recurrence_patterns') op.drop_table('recurrence_patterns') op.drop_index(op.f('ix_items_name'), table_name='items') op.drop_index(op.f('ix_items_id'), table_name='items') op.drop_table('items') op.drop_index(op.f('ix_lists_name'), table_name='lists') op.drop_index(op.f('ix_lists_id'), table_name='lists') op.drop_table('lists') op.drop_index('ix_invites_active_code', table_name='invites') op.drop_index(op.f('ix_invites_id'), table_name='invites') op.drop_index(op.f('ix_invites_code'), table_name='invites') op.drop_table('invites') op.drop_index(op.f('ix_user_groups_id'), table_name='user_groups') op.drop_table('user_groups') op.drop_index(op.f('ix_groups_name'), table_name='groups') op.drop_index(op.f('ix_groups_id'), table_name='groups') op.drop_table('groups') op.drop_index(op.f('ix_users_name'), table_name='users') op.drop_index(op.f('ix_users_id'), table_name='users') op.drop_index(op.f('ix_users_email'), table_name='users') op.drop_table('users') chore_type_enum.drop(op.get_bind(), checkfirst=False) chore_frequency_enum.drop(op.get_bind(), checkfirst=False) recurrence_type_enum.drop(op.get_bind(), checkfirst=False) expense_overall_status_enum.drop(op.get_bind(), checkfirst=False) expense_split_status_enum.drop(op.get_bind(), checkfirst=False) split_type_enum.drop(op.get_bind(), checkfirst=False) user_role_enum.drop(op.get_bind(), checkfirst=False)