Re: SQL:2011 application time

From: Paul Jungwirth <pj(at)illuminatedcomputing(dot)com>
To: Peter Eisentraut <peter(at)eisentraut(dot)org>, jian he <jian(dot)universality(at)gmail(dot)com>
Cc: PostgreSQL Hackers <pgsql-hackers(at)lists(dot)postgresql(dot)org>
Subject: Re: SQL:2011 application time
Date: 2023-10-11 04:47:01
Message-ID: dc8c8eab-9f7a-3189-4fd2-1ae1d50ac9b8@illuminatedcomputing.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-hackers

On 9/25/23 14:00, Peter Eisentraut wrote:
> Looking through the tests in v16-0001:
>
> +-- PK with no columns just WITHOUT OVERLAPS:
> +CREATE TABLE temporal_rng (
> +       valid_at tsrange,
> +       CONSTRAINT temporal_rng_pk PRIMARY KEY (valid_at WITHOUT OVERLAPS)
> +);
> +ERROR:  syntax error at or near "WITHOUT"
> +LINE 3:  CONSTRAINT temporal_rng_pk PRIMARY KEY (valid_at WITHOUT OV...
> +                                                          ^
>
> I think this error is confusing.  The SQL standard requires at least one
> non-period column in a PK.  I don't know why that is or why we should
> implement it.  But if we want to implement it, maybe we should enforce
> that in parse analysis rather than directly in the parser, to be able to
> produce a more friendly error message.

Okay.

(I think the reason the standard requires one non-period column is to
identify the "entity". If philosophically the row is an Aristotelian
proposition about that thing, the period qualifies it as true just
during some time span. So the scalar part is doing the work that a PK
conventionally does, and the period part does something else. Perhaps a
PK/UNIQUE constraint with no scalar part would still be useful, but not
very often I think, and I'm not sure it makes sense to call it PK/UNIQUE.)

> +-- PK with a range column/PERIOD that isn't there:
> +CREATE TABLE temporal_rng (
> +       id INTEGER,
> +       CONSTRAINT temporal_rng_pk PRIMARY KEY (id, valid_at WITHOUT
> OVERLAPS)
> +);
> +ERROR:  range or PERIOD "valid_at" in WITHOUT OVERLAPS does not exist
>
> I think here we should just produce a "column doesn't exist" error
> message, the same as if the "id" column was invalid.  We don't need to
> get into the details of what kind of column it should be.  That is done
> in the next test

I'll change it. The reason for the different wording is that it might
not be a column at all. It might be a PERIOD. So what about just "column
or PERIOD doesn't exist"? (Your suggestion is fine too though.)

> +ERROR:  column "valid_at" in WITHOUT OVERLAPS is not a range type
>
> Also, in any case it would be nice to have a location pointer here (for
> both cases).

Agreed.

> +-- PK with one column plus a range:
> +CREATE TABLE temporal_rng (
> +       -- Since we can't depend on having btree_gist here,
> +       -- use an int4range instead of an int.
> +       -- (The rangetypes regression test uses the same trick.)
> +       id int4range,
> +       valid_at tsrange,
> +       CONSTRAINT temporal_rng_pk PRIMARY KEY (id, valid_at WITHOUT
> OVERLAPS)
> +);
>
> I'm confused why you are using int4range here (and in further tests) for
> the scalar (non-range) part of the primary key.  Wouldn't a plaint int4
> serve here?

A plain int4 would be better, and it would match the normal use-case,
but you must have btree_gist to create an index like that, and the
regress tests can't assume we have that. Here is the part from
sql/rangetypes.sql I'm referring to:

--
-- Btree_gist is not included by default, so to test exclusion
-- constraints with range types, use singleton int ranges for the "="
-- portion of the constraint.
--

create table test_range_excl(
room int4range,
speaker int4range,
during tsrange,
exclude using gist (room with =, during with &&),
exclude using gist (speaker with =, during with &&)
);

> +SELECT pg_get_indexdef(conindid, 0, true) FROM pg_constraint WHERE
> conname = 'temporal_rng_pk';
> +                                pg_get_indexdef
> +-------------------------------------------------------------------------------
> + CREATE UNIQUE INDEX temporal_rng_pk ON temporal_rng USING gist (id,
> valid_at)
>
> Shouldn't this somehow show the operator classes for the columns?  We
> are using different operator classes for the id and valid_at columns,
> aren't we?

We only print the operator classes if they are not the default, so they
don't appear here.

I do suspect something more is desirable though. For exclusion
constraints we replace everything before the columns with just "EXCLUDE
USING gist". I could embed WITHOUT OVERLAPS but it's not valid syntax in
CREATE INDEX. Let me know if you have any ideas.

> +-- PK with USING INDEX (not possible):
> +CREATE TABLE temporal3 (
> +       id int4range,
> +       valid_at tsrange
> +);
> +CREATE INDEX idx_temporal3_uq ON temporal3 USING gist (id, valid_at);
> +ALTER TABLE temporal3
> +       ADD CONSTRAINT temporal3_pk
> +       PRIMARY KEY USING INDEX idx_temporal3_uq;
> +ERROR:  "idx_temporal3_uq" is not a unique index
> +LINE 2:  ADD CONSTRAINT temporal3_pk
> +             ^
> +DETAIL:  Cannot create a primary key or unique constraint using such an
> index.
>
> Could you also add a test where the index is unique and the whole thing
> does work?

No problem!

> Apart from the tests, how about renaming the column
> pg_constraint.contemporal to something like to conwithoutoverlaps?

Is that too verbose? I've got some code already changing it to
conoverlaps but I'm probably happier with conwithoutoverlaps, assuming
no one else minds it.

Yours,

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

In response to

Responses

Browse pgsql-hackers by date

  From Date Subject
Next Message Amit Langote 2023-10-11 05:08:25 Re: remaining sql/json patches
Previous Message Peter Geoghegan 2023-10-11 04:35:45 Re: interval_ops shall stop using btequalimage (deduplication)