Re: NOT ENFORCED constraint feature - Mailing list pgsql-hackers

From Peter Eisentraut
Subject Re: NOT ENFORCED constraint feature
Date
Msg-id 50f46903-20e1-4e23-918c-a6cfdf1a9f4a@eisentraut.org
Whole thread Raw
In response to Re: NOT ENFORCED constraint feature  (Álvaro Herrera <alvherre@alvh.no-ip.org>)
Responses Re: NOT ENFORCED constraint feature
List pgsql-hackers
On 12.02.25 12:13, Álvaro Herrera wrote:
> On 2025-Feb-12, Ashutosh Bapat wrote:
> 
>> I have been asking a different question: What's the use of
>> not-enforced constraints if we don't allow VALID, NOT ENFORCED state
>> for them?
> 
> That's a question for the SQL standards committee.  They may serve
> schema documentation purposes, for example.
> https://www.postgresql.eu/events/pgconfeu2024/schedule/session/5677-exploring-postgres-databases-with-graphs/
> 
>> OTOH, consider an application which "knows" that the constraint is
>> valid for the data (either because of checks at application level, or
>> because the data was replicated from some other system where the
>> cosntraints were applied). It's a natural ask to use the constraints
>> for, say optimization, but don't take unnecessary overhead of
>> validating them. VALID, NOT ENFORCED state helps in such a scenario.
>> Of course an application can misuse it (just like stable marking on a
>> function), but well ... they will be penalised for their misuse.
> 
> I disagree that we should see a VALID NOT ENFORCED constraint as one
> that can be used for query optimization purposes.  This is only going to
> bring users pain, because it's far too easy to misuse and they will get
> wrong query results, possibly without knowing for who knows how long.

I've been digging into the ISO archives for some more background on the 
intended meaning of this feature.

Result: "NOT ENFORCED" just means "off" or "disabled", "could contain 
anything".  You can use this to do data loads, or schema surgery, or 
things like that.  Or just if you want it for documentation.

This idea that a not-enforced constraint should contain valid data 
anyway is not supported by anything I could find written down.  I've 
heard that in discussions, but those could have been speculations.

(I still think that could be a feature, but it's clearly not this one, 
at least not in its default state.)

So considering that, I think a three-state system makes more sense. 
Something like:

1) NOT ENFORCED -- no data is checked
2) NOT VALID -- existing data is unchecked, new data is checked
3) ENFORCED -- all data is checked

Transitions:

(1) - [ ALTER TABLE ... ALTER CONSTRAINT ... NOT VALID ] -> (2)
(1) - [ ALTER TABLE ... ALTER CONSTRAINT ... ENFORCED ] -> (3)
(2) - [ ALTER TABLE ... VALIDATE CONSTRAINT ... ] -> (3)
(2|3) - [ ALTER TABLE ... ALTER CONSTRAINT ... NOT ENFORCED ] -> (1)
(3) - [ ALTER TABLE ... ALTER CONSTRAINT ... NOT VALID ] -> (2)




pgsql-hackers by date:

Previous
From: Andres Freund
Date:
Subject: Re: Small memory fixes for pg_createsubcriber
Next
From: Andres Freund
Date:
Subject: Re: Adding NetBSD and OpenBSD to Postgres CI