Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add PostgreSql TSRANGE/TSTZRANGE support #5297

Draft
wants to merge 6 commits into
base: master
Choose a base branch
from

Conversation

griffio
Copy link
Contributor

@griffio griffio commented Jun 11, 2024

👷 🚧 Add some support for TS Range type https://www.postgresql.org/docs/16/rangetypes.html#RANGETYPES-EXAMPLES

Types are mapped to string representations as there is no client side data type such as a range that is compatible (Kotlin ranges only implement open/closed on upper bounds). This is consistent with JSON, TSVECTOR types and uses OTHER type to bind the literal value for INSERTS and String for results (Ideally there would be a type mapping for the PostgreSql JDBC driver to use the PgObject type, however only PostgreSqlType is available to map types for both Jdbc/R2dbc ).

Note: Bind parameters for ranges must be cast e.g.

SELECT ?::tstzmultirange - range_agg(slot) AS availability                                                                                                                               FROM Appointment
WHERE slot && ?::tstzrange;

Range functions https://www.postgresql.org/docs/16/functions-range.html are used to work with ranges e.g extract lower and upper values to the client types LocalDateTime and OffSetDateTime e.g.

INSERT INTO room_reservation VALUES
    ('123A', '[2010-01-01 14:00, 2010-01-01 15:00)');
CREATE TABLE TsRanges(
  slot_ts TSRANGE NOT NULL,
  slot_tsz TSTZRANGE
);

SELECT LOWER(slot_ts) AS begin_ts, UPPER(slot_ts) AS end_ts,
LOWER(slot_tsz) AS begin_tsz, UPPER(slot_tsz) AS end_tsz,
EXTRACT (epoch FROM UPPER(slot_ts) - LOWER(slot_ts)) / 60
FROM TsRanges;

SELECT isempty(slot_ts),
 lower_inc(slot_ts), upper_inc(slot_ts),
 lower_inf(slot_ts), upper_inf(slot_ts),
 range_merge(slot_tsz, slot_tsz)
FROM TsRanges;

Also add basic support for EXCLUDE table constraints for range supported indexes

CREATE TABLE Reservations (
    start_time TSTZRANGE,
    finish_time TSTZRANGE,
    CONSTRAINT no_screening_time_overlap EXCLUDE USING GIST (finish_time WITH =, start_time WITH &&)
);

MultiRange support (Postgresql 14 or higher)

Allows useful arithmetic on ranges
e.g identify the available time slots that are not occupied by any appointments within a specified time range.

SELECT tsmultirange(tsrange('2010-01-01 14:30:00', '2010-01-01 15:30:00', '[]'))
 - range_agg(appointment_dates)
FROM Appointments
WHERE appointment_dates && tsrange('2010-01-01 14:30:00', '2010-01-01 15:30:00', '[]');

Updated the type resolver precedence order such that a SqlBinaryExpr must return a Boolean if one of the arguments is Boolean
e.g Otherwise SELECT '2011-01-10'::timestamp <@ '[2011-01-01,2011-03-01)'::tsrange would resolve as a TimeStamp and not Boolean

TODO:
Create issue for PR
Add some more Boolean range tests

@griffio griffio force-pushed the add-postgresql-ts-range branch 2 times, most recently from d824f0e to ec03293 Compare August 5, 2024 14:43
Add TSRANGE TSTZRANGE TSMULTIRANGE TSTZMULTIRANGE types

Add overlaps operator `&&` as this is only used by Ranges and Arrays

Add `constraint_exclude_operators` as this is a feature that relates to ranges in Table Constraints
Add TSTZRANGE, TSRANGE, TSMULTIRANGE, TSTZMULTIRANGE type bindings to parameters

Add TSTZRANGE, TSRANGE, TSMULTIRANGE, TSTZMULTIRANGE to type resolver
Add Contains, TsRanges and Overlap Expression mixin
Update Error message
Likely that given two types - boolean is the expected type
e.g contains operator
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Development

Successfully merging this pull request may close these issues.

1 participant