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鈥檒l occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add PostgreSql TSRANGE/TSTZRANGE support #5297

Draft
wants to merge 26 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.

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

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', '[]');

Note: 馃 Merge this after #5274

TODO:
Create issue for PR
More tests e.g cast SELECT '("2010-01-01 14:30:00+00","2010-01-01 15:30:00+00"]'::TSTZRANGE

griffio added 26 commits May 28, 2024 15:15
extract temporal fields
fixture test
integration test
todo - bindarg test "?" needs cast e.g `?::TIMESTAMP`
Add Support for:

SELECT EXTRACT(MONTH FROM DATE '2023-05-15');

SELECT EXTRACT(HOUR FROM TIME '10:30:45');
SELECT EXTRACT(MONTH FROM DATE '2023-05-15');

SELECT EXTRACT(HOUR FROM TIME '10:30:45');
To support Extract
Literal Date and Time tests
Integration Test for Extract
Add error to validate temporal types
Integration test for INTERVAL returns double(3)
Add latest temporal fields (22)
Add range functions
Allows ranges to be added as String via Other Object
Allows ranges to be returned as String representation
For range index use
integration test for functions
@> and <@ are shared by tsvector and json types

Range specific operators
'&&'  '<<' '>>'  '&>' '&<' '-|-'
TSRANGE, TSTZRANGE boolean operator
Fixture test
Integration test
used to create ranges
e.g tsrange('2010-01-01 14:30:00', '2010-01-01 15:30:00', '[]')
TSMULTIRANGE, TSTZMULTIRANGE

Add range_agg function - this is useful to have for multirange queries
A more complex query showing use of multiranges
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

None yet

1 participant