Skip to content

Commit

Permalink
Allow SQLValueFunction pushdown into compressed scan
Browse files Browse the repository at this point in the history
Since all SQLValueFunction are STABLE we can safely push them
down into the scan of the compressed chunk.
The following expressions are pushed down:
- CURRENT_DATE
- CURRENT_TIME
- CURRENT_TIME(p)
- CURRENT_TIMESTAMP
- CURRENT_TIMESTAMP(p)
- LOCALTIME
- LOCALTIME(p)
- LOCALTIMESTAMP
- LOCALTIMESTAMP(p)
- USER
- CURRENT_USER
- SESSION_USER
- CURRENT_CATALOG
- CURRENT_SCHEMA
  • Loading branch information
svenklemm committed Dec 19, 2023
1 parent a1f7d35 commit 301612a
Show file tree
Hide file tree
Showing 6 changed files with 216 additions and 0 deletions.
1 change: 1 addition & 0 deletions .unreleased/pr_6440
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
Implements: #6440 Allow SQLValueFunction pushdown into compressed scan
1 change: 1 addition & 0 deletions tsl/src/nodes/decompress_chunk/qual_pushdown.c
Original file line number Diff line number Diff line change
Expand Up @@ -354,6 +354,7 @@ modify_expression(Node *node, QualPushdownContext *context)
case T_Const:
case T_NullTest:
case T_Param:
case T_SQLValueFunction:
break;
case T_Var:
{
Expand Down
169 changes: 169 additions & 0 deletions tsl/test/expected/compression_qualpushdown.out
Original file line number Diff line number Diff line change
Expand Up @@ -345,3 +345,172 @@ EXPLAIN (costs off) SELECT '1' FROM deleteme_with_bytea WHERE bdata::text = '123

DROP table deleteme;
DROP table deleteme_with_bytea;
-- test sqlvaluefunction pushdown
CREATE TABLE svf_pushdown(time timestamptz, c_date date, c_time time, c_timetz timetz, c_timestamp timestamptz, c_name text);
SELECT table_name FROM create_hypertable('svf_pushdown', 'time');
NOTICE: adding not-null constraint to column "time"
table_name
--------------
svf_pushdown
(1 row)

ALTER TABLE svf_pushdown SET (timescaledb.compress,timescaledb.compress_segmentby='c_date,c_time, c_timetz,c_timestamp,c_name');
INSERT INTO svf_pushdown SELECT '2020-01-01';
SELECT compress_chunk(show_chunks('svf_pushdown'));
compress_chunk
------------------------------------------
_timescaledb_internal._hyper_11_12_chunk
(1 row)

-- constraints should be pushed down into scan below decompresschunk in all cases
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_date = CURRENT_DATE;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Index Scan using compress_hyper_12_13_chunk__compressed_hypertable_12_c_date_c_t on compress_hyper_12_13_chunk
Index Cond: (c_date = CURRENT_DATE)
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timetz = CURRENT_TIME;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Index Scan using compress_hyper_12_13_chunk__compressed_hypertable_12_c_date_c_t on compress_hyper_12_13_chunk
Index Cond: (c_timetz = CURRENT_TIME)
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timetz = CURRENT_TIME(1);
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Index Scan using compress_hyper_12_13_chunk__compressed_hypertable_12_c_date_c_t on compress_hyper_12_13_chunk
Index Cond: (c_timetz = CURRENT_TIME(1))
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timestamp = CURRENT_TIMESTAMP;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Index Scan using compress_hyper_12_13_chunk__compressed_hypertable_12_c_date_c_t on compress_hyper_12_13_chunk
Index Cond: (c_timestamp = CURRENT_TIMESTAMP)
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timestamp = CURRENT_TIMESTAMP(1);
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Index Scan using compress_hyper_12_13_chunk__compressed_hypertable_12_c_date_c_t on compress_hyper_12_13_chunk
Index Cond: (c_timestamp = CURRENT_TIMESTAMP(1))
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_time = LOCALTIME;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Index Scan using compress_hyper_12_13_chunk__compressed_hypertable_12_c_date_c_t on compress_hyper_12_13_chunk
Index Cond: (c_time = LOCALTIME)
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_time = LOCALTIME(1);
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Index Scan using compress_hyper_12_13_chunk__compressed_hypertable_12_c_date_c_t on compress_hyper_12_13_chunk
Index Cond: (c_time = LOCALTIME(1))
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timestamp = LOCALTIMESTAMP;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Index Scan using compress_hyper_12_13_chunk__compressed_hypertable_12_c_date_c_t on compress_hyper_12_13_chunk
Index Cond: (c_timestamp = LOCALTIMESTAMP)
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timestamp = LOCALTIMESTAMP(1);
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Index Scan using compress_hyper_12_13_chunk__compressed_hypertable_12_c_date_c_t on compress_hyper_12_13_chunk
Index Cond: (c_timestamp = LOCALTIMESTAMP(1))
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = USER;
QUERY PLAN
-----------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Seq Scan on compress_hyper_12_13_chunk
Filter: (c_name = USER)
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = CURRENT_USER;
QUERY PLAN
-----------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Seq Scan on compress_hyper_12_13_chunk
Filter: (c_name = CURRENT_USER)
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = SESSION_USER;
QUERY PLAN
-----------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Seq Scan on compress_hyper_12_13_chunk
Filter: (c_name = SESSION_USER)
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = CURRENT_CATALOG;
QUERY PLAN
-----------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Seq Scan on compress_hyper_12_13_chunk
Filter: (c_name = CURRENT_CATALOG)
(5 rows)

EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = CURRENT_SCHEMA;
QUERY PLAN
-----------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
-> Seq Scan on compress_hyper_12_13_chunk
Filter: (c_name = CURRENT_SCHEMA)
(5 rows)

-- current_query() is not a sqlvaluefunction and volatile so should not be pushed down
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = current_query();
QUERY PLAN
-----------------------------------------------------------
Custom Scan (ChunkAppend) on svf_pushdown
Chunks excluded during startup: 0
-> Custom Scan (DecompressChunk) on _hyper_11_12_chunk
Filter: (c_name = current_query())
-> Seq Scan on compress_hyper_12_13_chunk
(5 rows)

14 changes: 14 additions & 0 deletions tsl/test/expected/decompress_vector_qual.out
Original file line number Diff line number Diff line change
Expand Up @@ -569,6 +569,12 @@ select count(*) from vectorqual where ts > case when '2021-01-01'::timestamp < '
0
(1 row)

select count(*) from vectorqual where ts < LOCALTIMESTAMP + '3 years'::interval;
count
-------
5
(1 row)

-- This filter is not vectorized because the 'timestamp > timestamptz'
-- operator is stable, not immutable, because it uses the current session
-- timezone. We could transform it to something like
Expand Down Expand Up @@ -664,3 +670,11 @@ select * from date_table where ts < '2021-01-02';
01-01-2021
(1 row)

select * from date_table where ts < CURRENT_DATE;
ts
------------
01-03-2021
01-02-2021
01-01-2021
(3 rows)

28 changes: 28 additions & 0 deletions tsl/test/sql/compression_qualpushdown.sql
Original file line number Diff line number Diff line change
Expand Up @@ -153,3 +153,31 @@ EXPLAIN (costs off) SELECT '1' FROM deleteme_with_bytea WHERE bdata::text = '123

DROP table deleteme;
DROP table deleteme_with_bytea;

-- test sqlvaluefunction pushdown
CREATE TABLE svf_pushdown(time timestamptz, c_date date, c_time time, c_timetz timetz, c_timestamp timestamptz, c_name text);
SELECT table_name FROM create_hypertable('svf_pushdown', 'time');
ALTER TABLE svf_pushdown SET (timescaledb.compress,timescaledb.compress_segmentby='c_date,c_time, c_timetz,c_timestamp,c_name');

INSERT INTO svf_pushdown SELECT '2020-01-01';
SELECT compress_chunk(show_chunks('svf_pushdown'));

-- constraints should be pushed down into scan below decompresschunk in all cases
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_date = CURRENT_DATE;
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timetz = CURRENT_TIME;
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timetz = CURRENT_TIME(1);
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timestamp = CURRENT_TIMESTAMP;
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timestamp = CURRENT_TIMESTAMP(1);
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_time = LOCALTIME;
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_time = LOCALTIME(1);
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timestamp = LOCALTIMESTAMP;
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_timestamp = LOCALTIMESTAMP(1);
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = USER;
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = CURRENT_USER;
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = SESSION_USER;
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = CURRENT_CATALOG;
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = CURRENT_SCHEMA;

-- current_query() is not a sqlvaluefunction and volatile so should not be pushed down
EXPLAIN (costs off) SELECT * FROM svf_pushdown WHERE c_name = current_query();

3 changes: 3 additions & 0 deletions tsl/test/sql/decompress_vector_qual.sql
Original file line number Diff line number Diff line change
Expand Up @@ -176,6 +176,7 @@ select count(*) from vectorqual where ts > '2021-01-01 00:00:00'::timestamptz::t
select count(*) from vectorqual where ts > '2021-01-01 00:00:00'::timestamp - interval '1 day';
-- Expression that evaluates to Null.
select count(*) from vectorqual where ts > case when '2021-01-01'::timestamp < '2022-01-01'::timestamptz then null else '2021-01-01 00:00:00'::timestamp end;
select count(*) from vectorqual where ts < LOCALTIMESTAMP + '3 years'::interval;

-- This filter is not vectorized because the 'timestamp > timestamptz'
-- operator is stable, not immutable, because it uses the current session
Expand Down Expand Up @@ -220,3 +221,5 @@ select * from date_table where ts >= '2021-01-02';
select * from date_table where ts = '2021-01-02';
select * from date_table where ts <= '2021-01-02';
select * from date_table where ts < '2021-01-02';
select * from date_table where ts < CURRENT_DATE;

0 comments on commit 301612a

Please sign in to comment.