Skip to content

Commit

Permalink
Alembic revision to deal with changelog index hitting max int size. (#…
Browse files Browse the repository at this point in the history
…174)

* Alembic revision to deal with changelog index hitting max int size.

* Updated Changelog model to use BigInteger.

* Trying to work out BigInt upgrade.

* Uncommented function.

* Revert sequence to int in downgrade.

* Fixed integer type name. Removed unused BigInteger import in models.py
  • Loading branch information
tjacovich committed Nov 15, 2023
1 parent 271f49a commit cd757a2
Show file tree
Hide file tree
Showing 2 changed files with 56 additions and 0 deletions.
1 change: 1 addition & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -103,6 +103,7 @@ ENV/
# emacs
*~

local_config.py
logs
python/*
venv/*
Expand Down
55 changes: 55 additions & 0 deletions alembic/versions/2d2af8a9c996_upgrade_change_log.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,55 @@
"""upgrade_change_log
Revision ID: 2d2af8a9c996
Revises: 0155d2dff74e
Create Date: 2023-11-13 14:56:21.410177
"""

# revision identifiers, used by Alembic.
revision = '2d2af8a9c996'
down_revision = '0155d2dff74e'

from alembic import op
import sqlalchemy as sa




def upgrade():
op.execute('ALTER TABLE change_log ADD COLUMN big_id BIGINT;')
op.execute('CREATE FUNCTION set_new_id() RETURNS TRIGGER AS\n'\
'$BODY$\n'\
'BEGIN\n'\
'\t NEW.big_id := NEW.id;\n'\
'\t RETURN NEW;\n'\
'END\n'\
'$BODY$ LANGUAGE PLPGSQL;\n'\
'CREATE TRIGGER set_new_id_trigger BEFORE INSERT OR UPDATE ON {}\n'\
'FOR EACH ROW EXECUTE PROCEDURE set_new_id();\n'.format('change_log'))
op.execute('UPDATE change_log SET big_id=id')
op.execute('CREATE UNIQUE INDEX IF NOT EXISTS big_id_unique ON change_log(big_id);')
op.execute('ALTER TABLE change_log ADD CONSTRAINT big_id_not_null CHECK (big_id IS NOT NULL) NOT VALID;')
op.execute('ALTER TABLE change_log VALIDATE CONSTRAINT big_id_not_null;')
op.execute('ALTER TABLE change_log DROP CONSTRAINT change_log_pkey, ADD CONSTRAINT change_log_pkey PRIMARY KEY USING INDEX big_id_unique;')
op.execute('ALTER SEQUENCE change_log_id_seq OWNED BY change_log.big_id;')
op.execute("ALTER TABLE change_log ALTER COLUMN big_id SET DEFAULT nextval('change_log_id_seq');")
op.execute("ALTER TABLE change_log RENAME COLUMN id TO old_id;")
op.execute("ALTER TABLE change_log RENAME COLUMN big_id TO id;")
op.drop_column('change_log', 'old_id')
op.execute('ALTER SEQUENCE change_log_id_seq as bigint MAXVALUE 9223372036854775807')
# ### end Alembic commands ###


def downgrade():
op.add_column('change_log', sa.Column('smallid', sa.Integer(), unique=True))
op.execute('DELETE FROM change_log WHERE id > 2147483647')
op.execute('UPDATE change_log SET smallid=id')
op.alter_column('change_log', 'smallid', nullable=False)
op.drop_constraint('change_log_pkey', 'change_log', type_='primary')
op.create_primary_key("change_log_pkey", "change_log", ["smallid", ])
op.alter_column('change_log', 'id', nullable=False, new_column_name='old_id')
op.alter_column('change_log', 'smallid', nullable=False, new_column_name='id')
op.drop_column('change_log', 'old_id')
op.execute('ALTER SEQUENCE change_log_id_seq as integer MAXVALUE 2147483647')

0 comments on commit cd757a2

Please sign in to comment.