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-03-12 14:29:39 +00:00
parent ae5b0e143c
commit 186670e10e
4 changed files with 155 additions and 11 deletions

View File

@@ -903,7 +903,7 @@ class TemplateBase(db.Model):
postage = db.Column(db.String, nullable=True)
CheckConstraint("""
CASE WHEN template_type = 'letter' THEN
postage is not null and postage in ('first', 'second')
postage is not null and postage in ('first', 'second', 'europe', 'rest-of-world')
ELSE
postage is null
END
@@ -1352,10 +1352,13 @@ DVLA_RESPONSE_STATUS_SENT = 'Sent'
FIRST_CLASS = 'first'
SECOND_CLASS = 'second'
POSTAGE_TYPES = [FIRST_CLASS, SECOND_CLASS]
EUROPE = 'europe'
REST_OF_WORLD = 'rest-of-world'
RESOLVE_POSTAGE_FOR_FILE_NAME = {
FIRST_CLASS: 1,
SECOND_CLASS: 2
SECOND_CLASS: 2,
EUROPE: 'E',
REST_OF_WORLD: 'N',
}
@@ -1432,7 +1435,7 @@ class Notification(db.Model):
postage = db.Column(db.String, nullable=True)
CheckConstraint("""
CASE WHEN notification_type = 'letter' THEN
postage is not null and postage in ('first', 'second')
postage is not null and postage in ('first', 'second', 'europe', 'rest-of-world')
ELSE
postage is null
END
@@ -1697,13 +1700,6 @@ class NotificationHistory(db.Model, HistoryModel):
created_by_id = db.Column(UUID(as_uuid=True), nullable=True)
postage = db.Column(db.String, nullable=True)
CheckConstraint("""
CASE WHEN notification_type = 'letter' THEN
postage is not null and postage in ('first', 'second')
ELSE
postage is null
END
""")
document_download_count = db.Column(db.Integer, nullable=True)

View File

@@ -0,0 +1,80 @@
"""
Revision ID: 0321_update_postage_constraint_1
Revises: 0320_optimise_notifications
Create Date: 2020-03-11 12:01:41.533192
"""
from alembic import op
import sqlalchemy as sa
revision = '0321_update_postage_constraint_1'
down_revision = '0320_optimise_notifications'
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
""")
op.drop_constraint('chk_notification_history_postage_null', 'notification_history')
def downgrade():
pass
# To downgrade this migration and migrations 0320 and 0321 * 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,45 @@
"""
Revision ID: 0322_update_postage_constraint_2
Revises: 0321_update_postage_constraint_1
Create Date: 2020-03-12 12:01:41.533192
"""
from alembic import op
import sqlalchemy as sa
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,23 @@
"""
Revision ID: 0323_update_postage_constraint_3
Revises: 0322_update_postage_constraint_2
Create Date: 2020-03-12 12:01:41.533192
"""
from alembic import op
import sqlalchemy as sa
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