Re: SQL:2011 application time

From: Paul Jungwirth <pj(at)illuminatedcomputing(dot)com>
To: jian he <jian(dot)universality(at)gmail(dot)com>
Cc: Isaac Morland <isaac(dot)morland(at)gmail(dot)com>, Robert Haas <robertmhaas(at)gmail(dot)com>, Jeff Davis <pgsql(at)j-davis(dot)com>, Peter Eisentraut <peter(at)eisentraut(dot)org>, PostgreSQL Hackers <pgsql-hackers(at)lists(dot)postgresql(dot)org>
Subject: Re: SQL:2011 application time
Date: 2024-08-01 17:09:03
Message-ID: c002230c-8879-4b2c-ad05-585d6572347c@illuminatedcomputing.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-hackers

On 7/25/24 08:52, Paul Jungwirth wrote:
> Here is a patch moving the not-empty check into check_exclusion_or_unique_constraint. That is a more
> logical place for it than ExecConstraints, since WITHOUT OVERLAPS is part of the index constraint
> (not a CHECK constraint). At that point we've already looked up all the information we need. So
> there is no extra cost for non-temporal tables, and no need to change pg_class or add to the
> relcache. Also putting it there means we don't need any extra code to enforce non-empties when we
> build the index or do anything else with it.
>
> I think this is the nicest solution we can expect. It is even cleaner than the &&& ideas. So
> hopefully this gets us back to where we were when we decided to commit PKs & FKs to v17.
>
> As before, I've left the nonempty check as a separate patch to make reviewing easier, but when
> committing I would squash it with the PK patch.

Hello,

Here is an updated set of patches, rebased because the old patches no longer applied.

Also I have a question about foreign key RESTRICT behavior and the SQL spec.

I added some tests for a particular condition:
there are two adjacent referenced rows (sharing a scalar key part),
and a single referencing row whose time spans the transition between the referenced rows.
So graphing the records on a timeline, they look like this:

PK: |-----|-----|
FK: |-----|

Now suppose you simultaneously update both referenced rows to be like so:

PK: |---------|-|
FK: |-----|

Note that the FK's condition is still fulfilled.

In a NO ACTION constraint, we clearly should not raise an error (and we don't).

In a RESTRICT constraint, we *do* raise an error (but maybe we shouldn't).

Here is some specific SQL (added to the tests in these patches):

-- A PK update sliding the edge between two referenced rows:
INSERT INTO temporal_rng (id, valid_at) VALUES
('[6,7)', daterange('2018-01-01', '2018-02-01')),
('[6,7)', daterange('2018-02-01', '2018-03-01'));
INSERT INTO temporal_fk_rng2rng (id, valid_at, parent_id) VALUES
('[4,5)', daterange('2018-01-15', '2018-02-15'), '[6,7)');
UPDATE temporal_rng
SET valid_at = CASE WHEN lower(valid_at) = '2018-01-01'
THEN daterange('2018-01-01', '2018-01-05')
WHEN lower(valid_at) = '2018-02-01'
THEN daterange('2018-01-05', '2018-03-01') END
WHERE id = '[6,7)';

or if you prefer PERIODs:

-- A PK update sliding the edge between two referenced rows:
INSERT INTO temporal_per (id, valid_from, valid_til) VALUES
('[6,7)', '2018-01-01', '2018-02-01'),
('[6,7)', '2018-02-01', '2018-03-01');
INSERT INTO temporal_fk_per2per (id, valid_from, valid_til, parent_id) VALUES
('[4,5)', '2018-01-15', '2018-02-15', '[6,7)');
UPDATE temporal_per
SET valid_from = CASE WHEN valid_from = '2018-01-01' THEN '2018-01-01'
WHEN valid_from = '2018-02-01' THEN '2018-01-05' END::date,
valid_til = CASE WHEN valid_from = '2018-01-01' THEN '2018-01-05'
WHEN valid_from = '2018-02-01' THEN '2018-03-01' END::date
WHERE id = '[6,7)';

Here is what the SQL:2011 spec says (section 4.18.3.3 from Part 2 Foundation):

> ON UPDATE RESTRICT: any change to a referenced column in the referenced table is prohibited if
there is a matching row.

So that says we should raise an error.
But it seems clearly written with only non-temporal constraints in mind.
Is it really correct in the scenario above? The reference is still valid.
Does anyone know if the text has been updated in more recent versions of the standard?

Part of me is happy the standard says this, because not raising an error is harder to implement.
Maybe a lot harder.

On the other hand, what if we have just one row in each table, and we *expand* the referenced range?
In other words, from this:

PK: |-----|
FK: |-|

to this:

PK: |-------|
FK: |-|

Should that raise an error too? Currently it does not.

But I think that is correct. As usual I go back to Date's model about "one row per millisecond".
The referenced milliseconds didn't get updated, only the unreferenced ones.
So I think what we are doing is okay.

Likewise that same principle indicates we are doing the right thing in the original case:
we did update the referenced milliseconds.
Even though we swapped in replacements, we have to raise an error.
This is no different than the non-temporal case.

So my conclusion is we are doing the right thing in all places.
But here is an opportunity for people to disagree. :-)

Rebased to f5f30c22ed.

Yours,

--
Paul ~{:-)
pj(at)illuminatedcomputing(dot)com

Attachment Content-Type Size
v38-0001-Add-stratnum-GiST-support-function.patch text/x-patch 20.7 KB
v38-0002-Add-temporal-PRIMARY-KEY-and-UNIQUE-constraints.patch text/x-patch 147.5 KB
v38-0003-Forbid-empty-ranges-multiranges-in-WITHOUT-OVERL.patch text/x-patch 29.4 KB
v38-0004-Add-temporal-FOREIGN-KEY-contraints.patch text/x-patch 186.9 KB
v38-0005-Add-support-funcs-for-FOR-PORTION-OF.patch text/x-patch 43.0 KB
v38-0006-Add-UPDATE-DELETE-FOR-PORTION-OF.patch text/x-patch 160.3 KB
v38-0007-Add-CASCADE-SET-NULL-SET-DEFAULT-for-temporal-fo.patch text/x-patch 225.1 KB
v38-0008-Add-PERIODs.patch text/x-patch 335.1 KB

In response to

Browse pgsql-hackers by date

  From Date Subject
Next Message Michael Paquier 2024-08-01 17:11:34 Re: Flush pgstats file during checkpoints
Previous Message Nathan Bossart 2024-08-01 16:52:57 pg_dump: optimize dumpFunc()