separate notification postage constraint into three separate commits

we had an issue where the notification postage constraint command ran
into a deadlock, after trying to acquire two exclusive access locks on
large frequently modified/read tables.

To avoid this happening, we've had to split the upgrade script into
three - one script to apply the not-valid constraint to notifications
table, one for notification_history, and a third to validate the two
constraints.

Note: The first two scripts acquire exclusive access locks, but the
third only needs a row by row lock.

since this involves changing the exsiting alembic upgrades, if you've
upgraded your db you'll need to run the following three commands to
revert your database to a previous good state.

```
alter table notifications drop constraint chk_notifications_postage_null;
alter table notification_history drop constraint chk_notification_history_postage_null;
update alembic_version set version_num = '0229_new_letter_rates';
```
This commit is contained in:
Leo Hemsted
2018-09-27 15:20:28 +01:00
parent f73d9ef852
commit 2b354eb5df
4 changed files with 81 additions and 44 deletions

View File

@@ -1,44 +0,0 @@
"""
Revision ID: 0230_noti_postage_constraint
Revises: 0229_new_letter_rates
Create Date: 2018-09-19 11:42:52.229430
"""
from alembic import op
revision = '0230_noti_postage_constraint'
down_revision = '0229_new_letter_rates'
def upgrade():
op.execute("""
ALTER TABLE notifications ADD CONSTRAINT "chk_notifications_postage_null"
CHECK (
CASE WHEN notification_type = 'letter' THEN
postage is not null and postage in ('first', 'second')
ELSE
postage is null
END
)
NOT VALID
""")
op.execute("""
ALTER TABLE notification_history ADD CONSTRAINT "chk_notification_history_postage_null"
CHECK (
CASE WHEN notification_type = 'letter' THEN
postage is not null and postage in ('first', 'second')
ELSE
postage is null
END
)
NOT VALID
""")
op.execute('ALTER TABLE notifications VALIDATE CONSTRAINT "chk_notifications_postage_null"')
op.execute('ALTER TABLE notification_history VALIDATE CONSTRAINT "chk_notification_history_postage_null"')
def downgrade():
op.drop_constraint('chk_notifications_postage_null', 'notifications', type_='check')
op.drop_constraint('chk_notification_history_postage_null', 'notification_history', type_='check')

View File

@@ -0,0 +1,30 @@
"""
Revision ID: 0230_noti_postage_constraint_1
Revises: 0229_new_letter_rates
Create Date: 2018-09-19 11:42:52.229430
"""
from alembic import op
revision = '0230_noti_postage_constraint_1'
down_revision = '0229_new_letter_rates'
def upgrade():
op.execute("""
ALTER TABLE notifications ADD CONSTRAINT "chk_notifications_postage_null"
CHECK (
CASE WHEN notification_type = 'letter' THEN
postage is not null and postage in ('first', 'second')
ELSE
postage is null
END
)
NOT VALID
""")
def downgrade():
op.drop_constraint('chk_notifications_postage_null', 'notifications', type_='check')

View File

@@ -0,0 +1,30 @@
"""
Revision ID: 0230_noti_postage_constraint_2
Revises: 0230_noti_postage_constraint_1
Create Date: 2018-09-19 11:42:52.229430
"""
from alembic import op
revision = '0230_noti_postage_constraint_2'
down_revision = '0230_noti_postage_constraint_1'
def upgrade():
op.execute("""
ALTER TABLE notification_history ADD CONSTRAINT "chk_notification_history_postage_null"
CHECK (
CASE WHEN notification_type = 'letter' THEN
postage is not null and postage in ('first', 'second')
ELSE
postage is null
END
)
NOT VALID
""")
def downgrade():
op.drop_constraint('chk_notification_history_postage_null', 'notification_history', type_='check')

View File

@@ -0,0 +1,21 @@
"""
Revision ID: 0230_noti_postage_constraint_3
Revises: 0230_noti_postage_constraint_2
Create Date: 2018-09-19 11:42:52.229430
"""
from alembic import op
revision = '0230_noti_postage_constraint_3'
down_revision = '0230_noti_postage_constraint_2'
def upgrade():
op.execute('ALTER TABLE notifications VALIDATE CONSTRAINT "chk_notifications_postage_null"')
op.execute('ALTER TABLE notification_history VALIDATE CONSTRAINT "chk_notification_history_postage_null"')
def downgrade():
pass