On 7/18/24 11:39, Paul Jungwirth wrote:
So I swapped in the &&& patch, cleaned it up, and added tests. But something is wrong. After I get one failure from an empty, I keep getting failures, even though the table is empty:

regression=# truncate temporal_rng cascade;
NOTICE:  truncate cascades to table "temporal_fk_rng2rng"
TRUNCATE TABLE
regression=# insert into temporal_rng values ('[1,2)', 
'[2000-01-01,2010-01-01)'); -- ok so far
INSERT 0 1
regression=# insert into temporal_rng values ('[1,2)', 'empty'); -- should fail 
and does
ERROR:  range cannot be empty
regression=# insert into temporal_rng values ('[1,2)', 
'[2010-01-01,2020-01-01)'); -- uh oh
ERROR:  range cannot be empty
regression=# truncate temporal_rng cascade;
NOTICE:  truncate cascades to table "temporal_fk_rng2rng"
TRUNCATE TABLE
regression=# insert into temporal_rng values ('[1,2)', 
'[2000-01-01,2010-01-01)'); -- ok so far
INSERT 0 1
regression=# insert into temporal_rng values ('[1,2)', 
'[2010-01-01,2020-01-01)'); -- ok now
INSERT 0 1

It looks like the index is getting corrupted. Continuing from the above:

regression=# create extension pageinspect;
CREATE EXTENSION
regression=# select gist_page_items(get_raw_page('temporal_rng_pk', 0), 
'temporal_rng_pk');
                               gist_page_items
----------------------------------------------------------------------------
  (1,"(0,1)",40,f,"(id, valid_at)=(""[1,2)"", ""[2000-01-01,2010-01-01)"")")
  (2,"(0,2)",40,f,"(id, valid_at)=(""[1,2)"", ""[2010-01-01,2020-01-01)"")")
(2 rows)

regression=# insert into temporal_rng values ('[1,2)', 'empty');
ERROR:  range cannot be empty
regression=# select gist_page_items(get_raw_page('temporal_rng_pk', 0), 
'temporal_rng_pk');
                               gist_page_items
----------------------------------------------------------------------------
  (1,"(0,1)",40,f,"(id, valid_at)=(""[1,2)"", ""[2000-01-01,2010-01-01)"")")
  (2,"(0,2)",40,f,"(id, valid_at)=(""[1,2)"", ""[2010-01-01,2020-01-01)"")")
  (3,"(0,3)",32,f,"(id, valid_at)=(""[1,2)"", empty)")
(3 rows)

I realized this isn't index corruption, just MVCC. The exclusion constraint is 
checked after we
update the index, which is why the row gets left behind. But it doesn't cause 
any wrong answers, and
if you vacuum the table the row goes away.

This also explains my confusion here:

I thought of a possible problem: this operator works great if there are already rows in the table, but what if the *first row you insert* has an empty range? Then there is nothing to compare against, so the operator will never be used. Right?

Except when I test it, it still works!

The first row still does a comparison because when we check the exclusion 
constraint, there is a
comparison between the query and the key we just inserted. (When I say "query" 
I don't mean a SQL
query, but the value used to search the index that is compared against its 
keys.)

So I'm glad I didn't stumble on a GiST bug, but I think it means ereporting 
from an exclusion operator
is not a workable approach. Failures leave behind invalid tuples, and future 
(valid) tuples can fail if
we compare to those invalid tuples. Since MVCC visibility is stored in the 
heap, not in the index, it's
not really accessible to us here. So far I don't have any ideas to rescue this 
idea, even though I like
it a lot. So I will go back to the executor idea we discussed at pgconf.dev.

One tempting alternative though is to let exclusion constraints do the 
not-empty check, instead of
putting it in the executor. It would be an extra check we do only when the 
constraint has
pg_constraint.conperiod. Then we don't need to add & maintain 
pg_class.relwithoutoverlaps, and we don't
need a relcache change, and we don't need so much extra code to check existing 
rows when you add the
constraint. It doesn't use the existing available exclusion constraint 
functionality, but if we're
willing to extend the executor to know about WITHOUT OVERLAPS, I guess we could 
teach exclusion
constraints about it instead. Doing the check there does seem to have better 
locality with the feature.
So I think I will try that out as well.

Yours,

--
Paul              ~{:-)
p...@illuminatedcomputing.com


Reply via email to