Thread: functions allowed in CHECK constraints
Hello, I just tried specifying a function in a check constraint, (not being able to use a subquery or otherwise referencing rowsin another (parent) table) and this worked. However reading the docs do not point to any such direction, on the contrary docs say that subselects are not allowed. e.g. this fails as expected : alter table crew_eval_rankset_rank ADD CONSTRAINT ranksetid_chk CHECK((SELECT NOT appliestoall FROM crew_eval_rankset cerWHERE cer.id=ranksetid)); ERROR: cannot use subquery in check constraint while this works unexpectedly : create function crew_eval_ranksets_check_appliestoall (ranksetid int) RETURNS BOOLEAN LANGUAGE sql AS $$ SELECT NOT appliestoall FROM crew_eval_rankset cer WHERE cer.id=ranksetid $$; alter table crew_eval_rankset_rank ADD CONSTRAINT ranksetid_chk CHECK(crew_eval_ranksets_check_appliestoall(ranksetid)); insert into crew_eval_rankset(setname,appliestoall) VALUES('all ranks','t'); insert into crew_eval_rankset_rank (ranksetid , rankid) VALUES(3,70); ERROR: new row for relation "crew_eval_rankset_rank" violates check constraint "ranksetid_chk" So, what's the point in forbidding the use of subselects if one can use functions? And OTOH if effectively doing so is badfor some reason, why let it happen with a function? Basically, I tried this after reading : https://stackoverflow.com/questions/21791675/foreign-key-constraint-with-some-column-values-residing-in-other-tables/22023533#22023533 ,I wouldn't have thought doing it after reading the docs. -- Achilleas Mantzios
So, what's the point in forbidding the use of subselects if one can use functions? And OTOH if effectively doing so is bad for some reason, why let it happen with a function?
Short answer, the system treats the function as a black-box and doesn't know that you've used it to circumvent its prohibition on subselects. The prohibition still is in place though. If you use a function you are expected to ensure you do not violate any of the restrictions yourself.
The reason it is bad is because the query is only run at row insertion time - and if the external data that the subquery references changes the check constraint can become invalidated. If that happens at minimum a dump/restore will fail.
David J.
"David G. Johnston" <david.g.johnston@gmail.com> writes: > On Fri, Feb 9, 2018 at 1:37 AM, Achilleas Mantzios < > itdev@itdevel.internal.net> wrote: >> So, what's the point in forbidding the use of subselects if one can use >> functions? And OTOH if effectively doing so is bad for some reason, why let >> it happen with a function? > Short answer, the system treats the function as a black-box and doesn't > know that you've used it to circumvent its prohibition on subselects. The > prohibition still is in place though. If you use a function you are > expected to ensure you do not violate any of the restrictions yourself. Actually, I'd say that the possibility to use a function is a workaround for the fact that you can't write a sub-select directly ;-). The latter is more of an implementation restriction than anything else, stemming from the fact that we don't run CHECK expressions through the planner. Now, it's certainly true that you can use a sub-select to write a non-immutable CHECK expression and thereby shoot yourself in the foot. But you can shoot yourself in the foot that way without sub-selects, too. We do not try to enforce that CHECK expressions are immutable. regards, tom lane