Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

add pg_trgm extension and ensure the indexes are maintained during db update #124

Merged
merged 4 commits into from
Sep 11, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions migrations/script.py.mako
Original file line number Diff line number Diff line change
Expand Up @@ -18,6 +18,7 @@ depends_on = ${repr(depends_on)}


def upgrade() -> None:
op.execute('CREATE EXTENSION IF NOT EXISTS pg_trgm')
${upgrades if upgrades else "pass"}


Expand Down
36 changes: 36 additions & 0 deletions migrations/versions/46b4797494ca_remove_b_tree_indexes.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
"""remove b-tree indexes

Revision ID: 46b4797494ca
Revises: 94e3b0854cad
Create Date: 2024-09-11 13:10:17.186167

"""

from alembic import op

# revision identifiers, used by Alembic.
revision = '46b4797494ca'
down_revision = '94e3b0854cad'
branch_labels = None
depends_on = None


def upgrade() -> None:
op.execute('CREATE EXTENSION IF NOT EXISTS pg_trgm')
# ### commands auto generated by Alembic - please adjust! ###
op.drop_index('ix_credit_retirement_account', table_name='credit')
op.drop_index('ix_credit_retirement_beneficiary', table_name='credit')
op.drop_index('ix_credit_retirement_note', table_name='credit')
op.drop_index('ix_credit_retirement_reason', table_name='credit')
# ### end Alembic commands ###


def downgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
op.create_index('ix_credit_retirement_reason', 'credit', ['retirement_reason'], unique=False)
op.create_index('ix_credit_retirement_note', 'credit', ['retirement_note'], unique=False)
op.create_index(
'ix_credit_retirement_beneficiary', 'credit', ['retirement_beneficiary'], unique=False
)
op.create_index('ix_credit_retirement_account', 'credit', ['retirement_account'], unique=False)
# ### end Alembic commands ###
Original file line number Diff line number Diff line change
@@ -1,8 +1,8 @@
"""Rename credit transaction fields to reflect retirement context
"""reset migrations and add indexes

Revision ID: 8b97dd22cafd
Revision ID: 94e3b0854cad
Revises:
Create Date: 2024-09-05 14:30:52.228849
Create Date: 2024-09-10 19:03:00.335882

"""

Expand All @@ -12,13 +12,14 @@
from sqlalchemy.dialects import postgresql

# revision identifiers, used by Alembic.
revision = '8b97dd22cafd'
revision = '94e3b0854cad'
down_revision = None
branch_labels = None
depends_on = None


def upgrade() -> None:
op.execute('CREATE EXTENSION IF NOT EXISTS pg_trgm')
# ### commands auto generated by Alembic - please adjust! ###
op.create_table(
'clip',
Expand All @@ -33,6 +34,7 @@ def upgrade() -> None:
sa.Column('id', sa.Integer(), nullable=False),
sa.PrimaryKeyConstraint('id'),
)
op.create_index(op.f('ix_clip_id'), 'clip', ['id'], unique=False)
op.create_table(
'file',
sa.Column('id', sa.Integer(), nullable=False),
Expand All @@ -50,6 +52,7 @@ def upgrade() -> None:
),
sa.PrimaryKeyConstraint('id'),
)
op.create_index(op.f('ix_file_id'), 'file', ['id'], unique=False)
op.create_table(
'project',
sa.Column('project_id', sqlmodel.sql.sqltypes.AutoString(), nullable=False),
Expand All @@ -69,7 +72,21 @@ def upgrade() -> None:
sa.Column('project_url', sqlmodel.sql.sqltypes.AutoString(), nullable=True),
sa.PrimaryKeyConstraint('project_id'),
)
op.create_index(
'ix_project_name_gin',
'project',
[sa.text('lower(name) gin_trgm_ops')],
unique=False,
postgresql_using='gin',
)
op.create_index(op.f('ix_project_project_id'), 'project', ['project_id'], unique=True)
op.create_index(
'ix_project_project_id_gin',
'project',
[sa.text('lower(project_id) gin_trgm_ops')],
unique=False,
postgresql_using='gin',
)
op.create_table(
'clipproject',
sa.Column('id', sa.Integer(), nullable=False),
Expand All @@ -85,6 +102,9 @@ def upgrade() -> None:
),
sa.PrimaryKeyConstraint('id'),
)
op.create_index(op.f('ix_clipproject_clip_id'), 'clipproject', ['clip_id'], unique=False)
op.create_index(op.f('ix_clipproject_id'), 'clipproject', ['id'], unique=False)
op.create_index(op.f('ix_clipproject_project_id'), 'clipproject', ['project_id'], unique=False)
op.create_table(
'credit',
sa.Column('quantity', sa.BigInteger(), nullable=True),
Expand All @@ -107,31 +127,80 @@ def upgrade() -> None:
op.create_index(
op.f('ix_credit_retirement_account'), 'credit', ['retirement_account'], unique=False
)
op.create_index(
'ix_credit_retirement_account_gin',
'credit',
[sa.text('lower(retirement_account) gin_trgm_ops')],
unique=False,
postgresql_using='gin',
)
op.create_index(
op.f('ix_credit_retirement_beneficiary'), 'credit', ['retirement_beneficiary'], unique=False
)
op.create_index(
'ix_credit_retirement_beneficiary_gin',
'credit',
[sa.text('lower(retirement_beneficiary) gin_trgm_ops')],
unique=False,
postgresql_using='gin',
)
op.create_index(op.f('ix_credit_retirement_note'), 'credit', ['retirement_note'], unique=False)
op.create_index(
'ix_credit_retirement_note_gin',
'credit',
[sa.text('lower(retirement_note) gin_trgm_ops')],
unique=False,
postgresql_using='gin',
)
op.create_index(
op.f('ix_credit_retirement_reason'), 'credit', ['retirement_reason'], unique=False
)
op.create_index(
'ix_credit_retirement_reason_gin',
'credit',
[sa.text('lower(retirement_reason) gin_trgm_ops')],
unique=False,
postgresql_using='gin',
)
op.create_index(
op.f('ix_credit_transaction_date'), 'credit', ['transaction_date'], unique=False
)
op.create_index(
'ix_credit_transaction_type_gin',
'credit',
[sa.text('lower(transaction_type) gin_trgm_ops')],
unique=False,
postgresql_using='gin',
)
# ### end Alembic commands ###


def downgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
op.drop_index('ix_credit_transaction_type_gin', table_name='credit', postgresql_using='gin')
op.drop_index(op.f('ix_credit_transaction_date'), table_name='credit')
op.drop_index('ix_credit_retirement_reason_gin', table_name='credit', postgresql_using='gin')
op.drop_index(op.f('ix_credit_retirement_reason'), table_name='credit')
op.drop_index('ix_credit_retirement_note_gin', table_name='credit', postgresql_using='gin')
op.drop_index(op.f('ix_credit_retirement_note'), table_name='credit')
op.drop_index(
'ix_credit_retirement_beneficiary_gin', table_name='credit', postgresql_using='gin'
)
op.drop_index(op.f('ix_credit_retirement_beneficiary'), table_name='credit')
op.drop_index('ix_credit_retirement_account_gin', table_name='credit', postgresql_using='gin')
op.drop_index(op.f('ix_credit_retirement_account'), table_name='credit')
op.drop_index(op.f('ix_credit_project_id'), table_name='credit')
op.drop_table('credit')
op.drop_index(op.f('ix_clipproject_project_id'), table_name='clipproject')
op.drop_index(op.f('ix_clipproject_id'), table_name='clipproject')
op.drop_index(op.f('ix_clipproject_clip_id'), table_name='clipproject')
op.drop_table('clipproject')
op.drop_index('ix_project_project_id_gin', table_name='project', postgresql_using='gin')
op.drop_index(op.f('ix_project_project_id'), table_name='project')
op.drop_index('ix_project_name_gin', table_name='project', postgresql_using='gin')
op.drop_table('project')
op.drop_index(op.f('ix_file_id'), table_name='file')
op.drop_table('file')
op.drop_index(op.f('ix_clip_id'), table_name='clip')
op.drop_table('clip')
# ### end Alembic commands ###
60 changes: 48 additions & 12 deletions offsets_db_api/models.py
Original file line number Diff line number Diff line change
Expand Up @@ -3,13 +3,13 @@

import pydantic
from sqlalchemy.dialects import postgresql
from sqlmodel import BigInteger, Column, Field, Relationship, SQLModel, String
from sqlmodel import BigInteger, Column, Field, Index, Relationship, SQLModel, String, text

from offsets_db_api.schemas import FileCategory, FileStatus, Pagination


class File(SQLModel, table=True):
id: int = Field(default=None, primary_key=True)
id: int = Field(default=None, primary_key=True, index=True)
url: str
content_hash: str | None = Field(description='Hash of file contents')
status: FileStatus = Field(default='pending', description='Status of file processing')
Expand Down Expand Up @@ -55,6 +55,14 @@ class ProjectBase(SQLModel):


class Project(ProjectBase, table=True):
__table_args__ = (
Index(
'ix_project_project_id_gin',
text('lower(project_id) gin_trgm_ops'),
postgresql_using='gin',
),
Index('ix_project_name_gin', text('lower(name) gin_trgm_ops'), postgresql_using='gin'),
)
credits: list['Credit'] = Relationship(
back_populates='project',
sa_relationship_kwargs={
Expand Down Expand Up @@ -82,7 +90,7 @@ class ClipBase(SQLModel):


class Clip(ClipBase, table=True):
id: int = Field(default=None, primary_key=True)
id: int = Field(default=None, primary_key=True, index=True)
project_relationships: list['ClipProject'] = Relationship(
back_populates='clip', sa_relationship_kwargs={'cascade': 'all,delete,delete-orphan'}
)
Expand All @@ -99,9 +107,11 @@ class ClipwithProjects(ClipBase):


class ClipProject(SQLModel, table=True):
id: int = Field(default=None, primary_key=True)
clip_id: int = Field(description='Id of clip', foreign_key='clip.id')
project_id: str = Field(description='Id of project', foreign_key='project.project_id')
id: int = Field(default=None, primary_key=True, index=True)
clip_id: int = Field(description='Id of clip', foreign_key='clip.id', index=True)
project_id: str = Field(
description='Id of project', foreign_key='project.project_id', index=True
)
clip: Clip | None = Relationship(back_populates='project_relationships')
project: Project | None = Relationship(back_populates='clip_relationships')

Expand All @@ -117,15 +127,41 @@ class CreditBase(SQLModel):
vintage: int | None = Field(description='Vintage year of credits')
transaction_date: datetime.date | None = Field(description='Date of transaction', index=True)
transaction_type: str | None = Field(description='Type of transaction')
retirement_account: str | None = Field(
description='Account used for the transaction', index=True
)
retirement_beneficiary: str | None = Field(description='Beneficiary of credits', index=True)
retirement_reason: str | None = Field(description='Reason for transaction', index=True)
retirement_note: str | None = Field(description='Note', index=True)
retirement_account: str | None = Field(description='Account used for the transaction')
retirement_beneficiary: str | None = Field(description='Beneficiary of credits')
retirement_reason: str | None = Field(description='Reason for transaction')
retirement_note: str | None = Field(description='Note')


class Credit(CreditBase, table=True):
__table_args__ = (
Index(
'ix_credit_transaction_type_gin',
text('lower(transaction_type) gin_trgm_ops'),
postgresql_using='gin',
),
Index(
'ix_credit_retirement_account_gin',
text('lower(retirement_account) gin_trgm_ops'),
postgresql_using='gin',
),
Index(
'ix_credit_retirement_beneficiary_gin',
text('lower(retirement_beneficiary) gin_trgm_ops'),
postgresql_using='gin',
),
Index(
'ix_credit_retirement_reason_gin',
text('lower(retirement_reason) gin_trgm_ops'),
postgresql_using='gin',
),
Index(
'ix_credit_retirement_note_gin',
text('lower(retirement_note) gin_trgm_ops'),
postgresql_using='gin',
),
)

id: int = Field(default=None, primary_key=True)
project_id: str | None = Field(
description='Project id used by registry system',
Expand Down
Loading
Loading