Fix minmax-multi on infinite date/timestamp values

Make sure that infinite values in date/timestamp columns are treated as
if in infinite distance. Infinite values should not be merged with other
values, leaving them as outliers. The code however returned distance 0
in this case, so that infinite values were merged first. While this does
not break the index (i.e. it still produces correct query results), it
may make it much less efficient.

We don't need explicit handling of infinite date/timestamp values when
calculating distances, because those values are represented as extreme
but regular values (e.g. INT64_MIN/MAX for the timestamp type).

We don't need an exact distance, just a value that is much larger than
distanced between regular values. With the added cast to double values,
we can simply subtract the values.

The regression test queries a value in the "gap" and checks the range
was properly eliminated by the BRIN index.

This only affects minmax-multi indexes on timestamp/date columns with
infinite values, which is not very common in practice. The affected
indexes may need to be rebuilt.

Backpatch to 14, where minmax-multi indexes were introduced.

Reported-by: Ashutosh Bapat
Reviewed-by: Ashutosh Bapat, Dean Rasheed
Backpatch-through: 14
Discussion: https://postgr.es/m/eef0ea8c-4aaa-8d0d-027f-58b1f35dd170@enterprisedb.com
This commit is contained in:
Tomas Vondra 2023-10-27 17:57:28 +02:00
parent d1740e169d
commit 52c934cc1f
3 changed files with 96 additions and 6 deletions

View File

@ -2079,9 +2079,6 @@ brin_minmax_multi_distance_date(PG_FUNCTION_ARGS)
DateADT dateVal1 = PG_GETARG_DATEADT(0);
DateADT dateVal2 = PG_GETARG_DATEADT(1);
if (DATE_NOT_FINITE(dateVal1) || DATE_NOT_FINITE(dateVal2))
PG_RETURN_FLOAT8(0);
delta = (float8) dateVal2 - (float8) dateVal1;
Assert(delta >= 0);
@ -2140,9 +2137,6 @@ brin_minmax_multi_distance_timestamp(PG_FUNCTION_ARGS)
Timestamp dt1 = PG_GETARG_TIMESTAMP(0);
Timestamp dt2 = PG_GETARG_TIMESTAMP(1);
if (TIMESTAMP_NOT_FINITE(dt1) || TIMESTAMP_NOT_FINITE(dt2))
PG_RETURN_FLOAT8(0);
delta = (float8) dt2 - (float8) dt1;
Assert(delta >= 0);

View File

@ -498,6 +498,63 @@ SELECT * FROM brin_date_test WHERE a = '2023-01-01'::date;
Index Cond: (a = '2023-01-01'::date)
(4 rows)
DROP TABLE brin_date_test;
RESET enable_seqscan;
-- test handling of infinite timestamp values
CREATE TABLE brin_timestamp_test(a TIMESTAMP);
INSERT INTO brin_timestamp_test VALUES ('-infinity'), ('infinity');
INSERT INTO brin_timestamp_test
SELECT i FROM generate_series('2000-01-01'::timestamp, '2000-02-09'::timestamp, '1 day'::interval) s(i);
CREATE INDEX ON brin_timestamp_test USING brin (a timestamp_minmax_multi_ops) WITH (pages_per_range=1);
SET enable_seqscan = off;
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF)
SELECT * FROM brin_timestamp_test WHERE a = '2023-01-01'::timestamp;
QUERY PLAN
------------------------------------------------------------------------------
Bitmap Heap Scan on brin_timestamp_test (actual rows=0 loops=1)
Recheck Cond: (a = '2023-01-01 00:00:00'::timestamp without time zone)
-> Bitmap Index Scan on brin_timestamp_test_a_idx (actual rows=0 loops=1)
Index Cond: (a = '2023-01-01 00:00:00'::timestamp without time zone)
(4 rows)
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF)
SELECT * FROM brin_timestamp_test WHERE a = '1900-01-01'::timestamp;
QUERY PLAN
------------------------------------------------------------------------------
Bitmap Heap Scan on brin_timestamp_test (actual rows=0 loops=1)
Recheck Cond: (a = '1900-01-01 00:00:00'::timestamp without time zone)
-> Bitmap Index Scan on brin_timestamp_test_a_idx (actual rows=0 loops=1)
Index Cond: (a = '1900-01-01 00:00:00'::timestamp without time zone)
(4 rows)
DROP TABLE brin_timestamp_test;
RESET enable_seqscan;
-- test handling of infinite date values
CREATE TABLE brin_date_test(a DATE);
INSERT INTO brin_date_test VALUES ('-infinity'), ('infinity');
INSERT INTO brin_date_test SELECT '2000-01-01'::date + i FROM generate_series(1, 40) s(i);
CREATE INDEX ON brin_date_test USING brin (a date_minmax_multi_ops) WITH (pages_per_range=1);
SET enable_seqscan = off;
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF)
SELECT * FROM brin_date_test WHERE a = '2023-01-01'::date;
QUERY PLAN
-------------------------------------------------------------------------
Bitmap Heap Scan on brin_date_test (actual rows=0 loops=1)
Recheck Cond: (a = '2023-01-01'::date)
-> Bitmap Index Scan on brin_date_test_a_idx (actual rows=0 loops=1)
Index Cond: (a = '2023-01-01'::date)
(4 rows)
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF)
SELECT * FROM brin_date_test WHERE a = '1900-01-01'::date;
QUERY PLAN
-------------------------------------------------------------------------
Bitmap Heap Scan on brin_date_test (actual rows=0 loops=1)
Recheck Cond: (a = '1900-01-01'::date)
-> Bitmap Index Scan on brin_date_test_a_idx (actual rows=0 loops=1)
Index Cond: (a = '1900-01-01'::date)
(4 rows)
DROP TABLE brin_date_test;
RESET enable_seqscan;
RESET datestyle;

View File

@ -457,6 +457,45 @@ SET enable_seqscan = off;
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF)
SELECT * FROM brin_date_test WHERE a = '2023-01-01'::date;
DROP TABLE brin_date_test;
RESET enable_seqscan;
-- test handling of infinite timestamp values
CREATE TABLE brin_timestamp_test(a TIMESTAMP);
INSERT INTO brin_timestamp_test VALUES ('-infinity'), ('infinity');
INSERT INTO brin_timestamp_test
SELECT i FROM generate_series('2000-01-01'::timestamp, '2000-02-09'::timestamp, '1 day'::interval) s(i);
CREATE INDEX ON brin_timestamp_test USING brin (a timestamp_minmax_multi_ops) WITH (pages_per_range=1);
SET enable_seqscan = off;
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF)
SELECT * FROM brin_timestamp_test WHERE a = '2023-01-01'::timestamp;
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF)
SELECT * FROM brin_timestamp_test WHERE a = '1900-01-01'::timestamp;
DROP TABLE brin_timestamp_test;
RESET enable_seqscan;
-- test handling of infinite date values
CREATE TABLE brin_date_test(a DATE);
INSERT INTO brin_date_test VALUES ('-infinity'), ('infinity');
INSERT INTO brin_date_test SELECT '2000-01-01'::date + i FROM generate_series(1, 40) s(i);
CREATE INDEX ON brin_date_test USING brin (a date_minmax_multi_ops) WITH (pages_per_range=1);
SET enable_seqscan = off;
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF)
SELECT * FROM brin_date_test WHERE a = '2023-01-01'::date;
EXPLAIN (ANALYZE, TIMING OFF, COSTS OFF, SUMMARY OFF)
SELECT * FROM brin_date_test WHERE a = '1900-01-01'::date;
DROP TABLE brin_date_test;
RESET enable_seqscan;
RESET datestyle;