Update postage db constraints for international letters

The `notifications`, `notification_history`, `templates` and `templates_history`
tables all had a check constraint on the postage column which specified
that the postage had to be `first` or `second` if the notification or
template was a letter. We now have two more options for postage -
`europe` and `rest-of-world`.

It's not possible to alter a check constraint, so the constraints have
to be dropped then recreated. We are not recreating the constraint on
the `notification_history` table since values here are always copied
from the `notifications` table.

The constraints get added as `NOT VALID` at first - this stage will lock
the tables, so updating the `notification` table and `templates` and
`templates_history` are done in separate migrations so that we don't lock
all tables at the same time. In a third migration we then run
`VALIDATE CONSTRAINT` for all tables - this will lock a row at a time,
not the whole table.
This commit is contained in:
Katie Smith
2020-05-12 16:25:14 +01:00
parent c7f914122a
commit 7fd52017d0
4 changed files with 156 additions and 11 deletions

View File

@@ -0,0 +1,83 @@
"""
Revision ID: 0321_update_postage_constraint_1
Revises: 0320_optimise_notifications
Create Date: 2020-05-12 16:17:21.874281
"""
import os
from alembic import op
revision = '0321_update_postage_constraint_1'
down_revision = '0320_optimise_notifications'
environment = os.environ['NOTIFY_ENVIRONMENT']
def upgrade():
op.drop_constraint('chk_notifications_postage_null', 'notifications')
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', 'europe', 'rest-of-world')
ELSE
postage is null
END
)
NOT VALID
""")
if environment not in ["live", "production"]:
op.execute('ALTER TABLE notification_history DROP CONSTRAINT IF EXISTS chk_notification_history_postage_null')
def downgrade():
pass
# To downgrade this migration and migrations 0322 and 0323 * LOCALLY ONLY * use the following code.
# This should not be used in production - it will lock the tables for a long time
#
# op.drop_constraint('chk_notifications_postage_null', 'notifications')
# op.drop_constraint('chk_templates_postage', 'templates')
# op.drop_constraint('chk_templates_history_postage', 'templates_history')
#
# 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
# )
# """)
# 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
# )
# """)
# op.execute("""
# ALTER TABLE templates ADD CONSTRAINT "chk_templates_postage"
# CHECK (
# CASE WHEN template_type = 'letter' THEN
# postage is not null and postage in ('first', 'second')
# ELSE
# postage is null
# END
# )
# """)
# op.execute("""
# ALTER TABLE templates_history ADD CONSTRAINT "chk_templates_history_postage"
# CHECK (
# CASE WHEN template_type = 'letter' THEN
# postage is not null and postage in ('first', 'second')
# ELSE
# postage is null
# END
# )
# """)

View File

@@ -0,0 +1,44 @@
"""
Revision ID: 0322_update_postage_constraint_2
Revises: 0321_update_postage_constraint_1
Create Date: 2020-05-12 16:20:16.548347
"""
from alembic import op
revision = '0322_update_postage_constraint_2'
down_revision = '0321_update_postage_constraint_1'
def upgrade():
op.drop_constraint('chk_templates_postage', 'templates')
op.drop_constraint('chk_templates_history_postage', 'templates_history')
op.execute("""
ALTER TABLE templates ADD CONSTRAINT "chk_templates_postage"
CHECK (
CASE WHEN template_type = 'letter' THEN
postage is not null and postage in ('first', 'second', 'europe', 'rest-of-world')
ELSE
postage is null
END
)
NOT VALID
""")
op.execute("""
ALTER TABLE templates_history ADD CONSTRAINT "chk_templates_history_postage"
CHECK (
CASE WHEN template_type = 'letter' THEN
postage is not null and postage in ('first', 'second', 'europe', 'rest-of-world')
ELSE
postage is null
END
)
NOT VALID
""")
def downgrade():
pass

View File

@@ -0,0 +1,22 @@
"""
Revision ID: 0323_update_postage_constraint_3
Revises: 0322_update_postage_constraint_2
Create Date: 2020-05-12 16:21:56.210025
"""
from alembic import op
revision = '0323_update_postage_constraint_3'
down_revision = '0322_update_postage_constraint_2'
def upgrade():
op.execute('ALTER TABLE notifications VALIDATE CONSTRAINT "chk_notifications_postage_null"')
op.execute('ALTER TABLE templates VALIDATE CONSTRAINT "chk_templates_postage"')
op.execute('ALTER TABLE templates_history VALIDATE CONSTRAINT "chk_templates_history_postage"')
def downgrade():
pass