-
-
Notifications
You must be signed in to change notification settings - Fork 3
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #33 from CrimeIsDown/partitioning-setup
Adding new columns and indexes to the database
- Loading branch information
Showing
10 changed files
with
204 additions
and
26 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -74,5 +74,4 @@ jobs: | |
run: | | ||
docker compose --ansi never logs -f & | ||
sleep 10 | ||
uv run alembic upgrade head | ||
./make.sh test -s |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
59 changes: 59 additions & 0 deletions
59
app/alembic/versions/09874b204f9e_add_columns_to_calls_table.py
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,59 @@ | ||
"""add columns to calls table | ||
Revision ID: 09874b204f9e | ||
Revises: 71fea3333d68 | ||
Create Date: 2025-01-04 19:20:20.623118 | ||
""" | ||
|
||
from typing import Sequence, Union | ||
|
||
from alembic import op | ||
import sqlalchemy as sa | ||
|
||
from app.models.models import CALLS_TABLE_NAME | ||
|
||
|
||
# revision identifiers, used by Alembic. | ||
revision: str = "09874b204f9e" | ||
down_revision: Union[str, None] = "71fea3333d68" | ||
branch_labels: Union[str, Sequence[str], None] = None | ||
depends_on: Union[str, Sequence[str], None] = None | ||
|
||
|
||
def upgrade() -> None: | ||
op.alter_column(CALLS_TABLE_NAME, "raw_metadata", nullable=False) | ||
op.alter_column(CALLS_TABLE_NAME, "raw_audio_url", nullable=False) | ||
op.add_column( | ||
CALLS_TABLE_NAME, | ||
sa.Column("start_time", sa.TIMESTAMP(timezone=True), nullable=True), | ||
) | ||
op.add_column( | ||
CALLS_TABLE_NAME, sa.Column("transcript_plaintext", sa.Text(), nullable=True) | ||
) | ||
op.execute( | ||
f""" | ||
UPDATE {CALLS_TABLE_NAME} | ||
SET transcript_plaintext = ( | ||
SELECT string_agg(element->>1, E'\\n') | ||
FROM json_array_elements(raw_transcript::json) AS element | ||
) | ||
WHERE raw_transcript IS NOT NULL | ||
""" | ||
) | ||
op.execute( | ||
f""" | ||
UPDATE {CALLS_TABLE_NAME} | ||
SET start_time = to_timestamp((raw_metadata->>'start_time')::bigint) | ||
""" | ||
) | ||
op.alter_column( | ||
CALLS_TABLE_NAME, "start_time", server_default=sa.text("now()"), nullable=False | ||
) | ||
|
||
|
||
def downgrade() -> None: | ||
op.drop_column(CALLS_TABLE_NAME, "transcript_plaintext") | ||
op.drop_column(CALLS_TABLE_NAME, "start_time") | ||
op.alter_column(CALLS_TABLE_NAME, "raw_audio_url", nullable=True) | ||
op.alter_column(CALLS_TABLE_NAME, "raw_metadata", nullable=True) |
92 changes: 92 additions & 0 deletions
92
app/alembic/versions/17dc425f0a6a_add_indexes_to_calls_table.py
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,92 @@ | ||
"""add indexes to calls table | ||
Revision ID: 17dc425f0a6a | ||
Revises: 09874b204f9e | ||
Create Date: 2025-01-04 21:49:40.293750 | ||
""" | ||
|
||
from typing import Sequence, Union | ||
|
||
from alembic import op | ||
import sqlalchemy as sa | ||
|
||
from app.models.models import CALLS_TABLE_NAME | ||
|
||
|
||
# revision identifiers, used by Alembic. | ||
revision: str = "17dc425f0a6a" | ||
down_revision: Union[str, None] = "09874b204f9e" | ||
branch_labels: Union[str, Sequence[str], None] = None | ||
depends_on: Union[str, Sequence[str], None] = None | ||
|
||
|
||
def upgrade() -> None: | ||
# Create indexes concurrently to avoid locking the table; this requires us to do this outside a transaction block | ||
with op.get_context().autocommit_block(): | ||
op.create_index( | ||
"idx_short_name", | ||
CALLS_TABLE_NAME, | ||
[sa.text("(raw_metadata->>'short_name')")], | ||
postgresql_concurrently=True, | ||
) | ||
op.create_index( | ||
"idx_talkgroup_group", | ||
CALLS_TABLE_NAME, | ||
[sa.text("(raw_metadata->>'talkgroup_group')")], | ||
postgresql_concurrently=True, | ||
) | ||
op.create_index( | ||
"idx_talkgroup_group_tag", | ||
CALLS_TABLE_NAME, | ||
[sa.text("(raw_metadata->>'talkgroup_group_tag')")], | ||
postgresql_concurrently=True, | ||
) | ||
op.create_index( | ||
"idx_talkgroup_id", | ||
CALLS_TABLE_NAME, | ||
[sa.text("(raw_metadata->>'talkgroup')")], | ||
postgresql_concurrently=True, | ||
) | ||
op.create_index( | ||
"idx_talkgroup_tag", | ||
CALLS_TABLE_NAME, | ||
[sa.text("(raw_metadata->>'talkgroup_tag')")], | ||
postgresql_concurrently=True, | ||
) | ||
op.create_index( | ||
"idx_start_time", | ||
CALLS_TABLE_NAME, | ||
["start_time"], | ||
postgresql_concurrently=True, | ||
) | ||
|
||
|
||
def downgrade() -> None: | ||
with op.get_context().autocommit_block(): | ||
op.drop_index( | ||
"idx_short_name", table_name=CALLS_TABLE_NAME, postgresql_concurrently=True | ||
) | ||
op.drop_index( | ||
"idx_talkgroup_group", | ||
table_name=CALLS_TABLE_NAME, | ||
postgresql_concurrently=True, | ||
) | ||
op.drop_index( | ||
"idx_talkgroup_group_tag", | ||
table_name=CALLS_TABLE_NAME, | ||
postgresql_concurrently=True, | ||
) | ||
op.drop_index( | ||
"idx_talkgroup_id", | ||
table_name=CALLS_TABLE_NAME, | ||
postgresql_concurrently=True, | ||
) | ||
op.drop_index( | ||
"idx_talkgroup_tag", | ||
table_name=CALLS_TABLE_NAME, | ||
postgresql_concurrently=True, | ||
) | ||
op.drop_index( | ||
"idx_start_time", table_name=CALLS_TABLE_NAME, postgresql_concurrently=True | ||
) |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters