fix null check in constraint

There are two fun quirks of postgres/sql that we need to work around:
* any `x = y` where x or y is NULL returns NULL, rather than false.
* check constraints accept NULL or true values as good.

so, the check `postage in ('first', 'second')` returns `null` rather
than `false` when postage is null itself. This surprisingly passes the
check constraint. To get around this, we have to add an explicit not
null check as well.
This commit is contained in:
Leo Hemsted
2018-09-25 14:06:36 +01:00
parent 17612e5446
commit 3739c573ea
2 changed files with 4 additions and 4 deletions

View File

@@ -1193,7 +1193,7 @@ class Notification(db.Model):
postage = db.Column(db.String, nullable=True) postage = db.Column(db.String, nullable=True)
CheckConstraint(""" CheckConstraint("""
CASE WHEN notification_type = 'letter' THEN CASE WHEN notification_type = 'letter' THEN
postage in ('first', 'second') postage is not null and postage in ('first', 'second')
ELSE ELSE
postage is null postage is null
END END
@@ -1453,7 +1453,7 @@ class NotificationHistory(db.Model, HistoryModel):
postage = db.Column(db.String, nullable=True) postage = db.Column(db.String, nullable=True)
CheckConstraint(""" CheckConstraint("""
CASE WHEN notification_type = 'letter' THEN CASE WHEN notification_type = 'letter' THEN
postage in ('first', 'second') postage is not null and postage in ('first', 'second')
ELSE ELSE
postage is null postage is null
END END

View File

@@ -17,7 +17,7 @@ def upgrade():
ALTER TABLE notifications ADD CONSTRAINT "chk_notifications_postage_null" ALTER TABLE notifications ADD CONSTRAINT "chk_notifications_postage_null"
CHECK ( CHECK (
CASE WHEN notification_type = 'letter' THEN CASE WHEN notification_type = 'letter' THEN
postage in ('first', 'second') postage is not null and postage in ('first', 'second')
ELSE ELSE
postage is null postage is null
END END
@@ -28,7 +28,7 @@ def upgrade():
ALTER TABLE notification_history ADD CONSTRAINT "chk_notification_history_postage_null" ALTER TABLE notification_history ADD CONSTRAINT "chk_notification_history_postage_null"
CHECK ( CHECK (
CASE WHEN notification_type = 'letter' THEN CASE WHEN notification_type = 'letter' THEN
postage in ('first', 'second') postage is not null and postage in ('first', 'second')
ELSE ELSE
postage is null postage is null
END END