Skip to content

Commit

Permalink
Per @svenklemm reviews:
Browse files Browse the repository at this point in the history
- Allow FROM ONLY when joining with a regular table
- Allow joining with a regular view
  • Loading branch information
fabriziomello committed Jul 9, 2024
1 parent 658deaa commit d7fb0bd
Show file tree
Hide file tree
Showing 4 changed files with 92 additions and 50 deletions.
16 changes: 7 additions & 9 deletions tsl/src/continuous_aggs/common.c
Original file line number Diff line number Diff line change
Expand Up @@ -691,8 +691,10 @@ cagg_validate_query(const Query *query, const bool finalized, const char *cagg_s

if (inner_rte->rtekind == RTE_RELATION)
{
if (ts_is_hypertable(inner_rte->relid) ||
ts_continuous_agg_find_by_relid(inner_rte->relid))
bool is_hypertable = ts_is_hypertable(inner_rte->relid) ||
ts_continuous_agg_find_by_relid(inner_rte->relid);

if (is_hypertable)
{
num_hypertables++;
if (rte == NULL)
Expand All @@ -701,18 +703,14 @@ cagg_validate_query(const Query *query, const bool finalized, const char *cagg_s
else
{
num_tables++;
if (inner_rte->relkind == RELKIND_VIEW)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("invalid continuous aggregate view"),
errdetail("Views are not supported in continuous aggregates.")));
}

if (inner_rte->inh == false)
if (is_hypertable && inner_rte->inh == false)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("invalid continuous aggregate view"),
errdetail("FROM ONLY is not allowed in continuous aggregate.")));
errdetail(
"FROM ONLY on hypertables is not allowed in continuous aggregate.")));
}

/* Only inner joins are allowed. */
Expand Down
2 changes: 1 addition & 1 deletion tsl/test/expected/cagg_errors.out
Original file line number Diff line number Diff line change
Expand Up @@ -204,7 +204,7 @@ Select sum(humidity), avg(temperature::int4)
from ONLY conditions
group by time_bucket('1week', timec) , location WITH NO DATA;
ERROR: invalid continuous aggregate view
DETAIL: FROM ONLY is not allowed in continuous aggregate.
DETAIL: FROM ONLY on hypertables is not allowed in continuous aggregate.
--grouping sets and variants
CREATE MATERIALIZED VIEW mat_m1 WITH (timescaledb.continuous, timescaledb.materialized_only=false)
AS
Expand Down
93 changes: 56 additions & 37 deletions tsl/test/expected/cagg_joins.out
Original file line number Diff line number Diff line change
Expand Up @@ -724,6 +724,38 @@ SELECT * FROM cagg_reorder_using;
Wed Jun 30 17:00:00 2021 PDT | 28.0000000000000000 | thermo_3
(16 rows)

-- Cagg join with another table using FROM ONLY
CREATE MATERIALIZED VIEW cagg_from_only
WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS
SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
AVG(temperature),
name
FROM ONLY devices JOIN conditions USING (device_id)
GROUP BY name, bucket
ORDER BY bucket;
NOTICE: refreshing continuous aggregate "cagg_from_only"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
SELECT * FROM cagg_from_only;
bucket | avg | name
------------------------------+---------------------+----------
Sun Jun 13 17:00:00 2021 PDT | 26.0000000000000000 | thermo_1
Mon Jun 14 17:00:00 2021 PDT | 22.0000000000000000 | thermo_2
Tue Jun 15 17:00:00 2021 PDT | 24.0000000000000000 | thermo_3
Wed Jun 16 17:00:00 2021 PDT | 24.0000000000000000 | thermo_4
Thu Jun 17 17:00:00 2021 PDT | 27.0000000000000000 | thermo_4
Fri Jun 18 17:00:00 2021 PDT | 28.0000000000000000 | thermo_4
Sat Jun 19 17:00:00 2021 PDT | 30.0000000000000000 | thermo_1
Sun Jun 20 17:00:00 2021 PDT | 31.0000000000000000 | thermo_1
Mon Jun 21 17:00:00 2021 PDT | 34.0000000000000000 | thermo_1
Tue Jun 22 17:00:00 2021 PDT | 34.0000000000000000 | thermo_2
Wed Jun 23 17:00:00 2021 PDT | 34.0000000000000000 | thermo_2
Thu Jun 24 17:00:00 2021 PDT | 32.0000000000000000 | thermo_3
Fri Jun 25 17:00:00 2021 PDT | 32.0000000000000000 | thermo_3
Sat Jun 26 17:00:00 2021 PDT | 31.0000000000000000 | thermo_3
Tue Jun 29 17:00:00 2021 PDT | 28.0000000000000000 | thermo_3
Wed Jun 30 17:00:00 2021 PDT | 28.0000000000000000 | thermo_3
(16 rows)

-- Create CAgg with join and additional WHERE conditions
CREATE MATERIALIZED VIEW cagg_more_conds
WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS
Expand Down Expand Up @@ -795,8 +827,8 @@ SELECT * FROM cagg_on_cagg;

DROP MATERIALIZED VIEW cagg_on_cagg CASCADE;
NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to table _timescaledb_internal._hyper_17_59_chunk
drop cascades to table _timescaledb_internal._hyper_17_60_chunk
DETAIL: drop cascades to table _timescaledb_internal._hyper_18_61_chunk
drop cascades to table _timescaledb_internal._hyper_18_62_chunk
-- Nested CAgg over a CAgg with JOIN clause
CREATE MATERIALIZED VIEW cagg_on_cagg_join
WITH (timescaledb.continuous, timescaledb.materialized_only=true) AS
Expand Down Expand Up @@ -830,8 +862,8 @@ SELECT * FROM cagg_on_cagg_join;

DROP MATERIALIZED VIEW cagg_on_cagg_join CASCADE;
NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to table _timescaledb_internal._hyper_18_61_chunk
drop cascades to table _timescaledb_internal._hyper_18_62_chunk
DETAIL: drop cascades to table _timescaledb_internal._hyper_19_63_chunk
drop cascades to table _timescaledb_internal._hyper_19_64_chunk
-- Create CAgg with join and ORDER BY
CREATE MATERIALIZED VIEW cagg_ordered
WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS
Expand Down Expand Up @@ -913,8 +945,8 @@ NOTICE: refreshing continuous aggregate "cagg_nested"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
DROP MATERIALIZED VIEW cagg_nested CASCADE;
NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to table _timescaledb_internal._hyper_23_71_chunk
drop cascades to table _timescaledb_internal._hyper_23_72_chunk
DETAIL: drop cascades to table _timescaledb_internal._hyper_24_73_chunk
drop cascades to table _timescaledb_internal._hyper_24_74_chunk
-- CAgg with multiple join conditions without JOIN clause
CREATE MATERIALIZED VIEW cagg_more_joins_conds
WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS
Expand All @@ -938,8 +970,7 @@ LATERAL (SELECT * FROM mat_t1 WHERE mat_t1.a = conditions.temperature) q
GROUP BY bucket, temperature;
NOTICE: refreshing continuous aggregate "mat_m1"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
-- With FROM clause has view
\set ON_ERROR_STOP 0
-- Joining a hypertable and view
CREATE MATERIALIZED VIEW cagg_view
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
Expand All @@ -949,11 +980,12 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
FROM conditions, devices_view
WHERE conditions.device_id = devices_view.device_id
GROUP BY name, bucket, devices_view.device_id;
ERROR: invalid continuous aggregate view
DETAIL: Views are not supported in continuous aggregates.
NOTICE: refreshing continuous aggregate "cagg_view"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
CREATE TABLE cities(name text, currency text);
INSERT INTO cities VALUES ('Berlin', 'EUR'), ('London', 'PND');
--Error out when FROM clause has sub selects
\set ON_ERROR_STOP 0
CREATE MATERIALIZED VIEW conditions_summary_subselect
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
Expand Down Expand Up @@ -1087,6 +1119,15 @@ FROM conditions FULL JOIN devices
ON conditions.device_id = devices.device_id
GROUP BY name, bucket;
ERROR: only INNER or LEFT joins are supported in continuous aggregates
CREATE MATERIALIZED VIEW cagg_right
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
AVG(temperature),
name
FROM conditions RIGHT JOIN devices
ON conditions.device_id = devices.device_id
GROUP BY name, bucket;
ERROR: only INNER or LEFT joins are supported in continuous aggregates
\set ON_ERROR_STOP 1
CREATE MATERIALIZED VIEW cagg_left_join
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
Expand All @@ -1098,7 +1139,7 @@ ON conditions.device_id = devices.device_id
GROUP BY name, bucket;
NOTICE: refreshing continuous aggregate "cagg_left_join"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
--Error out for join between cagg and hypertable
-- Error out for join between cagg and hypertable
\set ON_ERROR_STOP 0
CREATE MATERIALIZED VIEW cagg_nested_ht
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
Expand All @@ -1124,35 +1165,12 @@ GROUP BY bucket, devices.name, location.name;
NOTICE: refreshing continuous aggregate "conditions_by_day"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
\set VERBOSITY terse
SET client_min_messages TO WARNING;
DROP TABLE conditions CASCADE;
NOTICE: drop cascades to 67 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
DROP TABLE devices CASCADE;
NOTICE: drop cascades to view devices_view
DROP TABLE conditions_dup CASCADE;
DROP TABLE devices_dup CASCADE;
RESET client_min_messages;
\set VERBOSITY default
-- SDC #1859
CREATE TABLE conditions(
Expand Down Expand Up @@ -1193,6 +1211,7 @@ SELECT a.* FROM cagg_realtime a WHERE a.location = 'Moscow' ORDER BY bucket LIMI
(2 rows)

\set VERBOSITY terse
SET client_min_messages TO WARNING;
DROP TABLE conditions CASCADE;
NOTICE: drop cascades to 3 other objects
DROP TABLE devices CASCADE;
RESET client_min_messages;
31 changes: 28 additions & 3 deletions tsl/test/sql/cagg_joins.sql
Original file line number Diff line number Diff line change
Expand Up @@ -233,6 +233,18 @@ ORDER BY bucket;

SELECT * FROM cagg_reorder_using;

-- Cagg join with another table using FROM ONLY
CREATE MATERIALIZED VIEW cagg_from_only
WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS
SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
AVG(temperature),
name
FROM ONLY devices JOIN conditions USING (device_id)
GROUP BY name, bucket
ORDER BY bucket;

SELECT * FROM cagg_from_only;

-- Create CAgg with join and additional WHERE conditions
CREATE MATERIALIZED VIEW cagg_more_conds
WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS
Expand Down Expand Up @@ -368,8 +380,7 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket, temperature, count(*) from
LATERAL (SELECT * FROM mat_t1 WHERE mat_t1.a = conditions.temperature) q
GROUP BY bucket, temperature;

-- With FROM clause has view
\set ON_ERROR_STOP 0
-- Joining a hypertable and view
CREATE MATERIALIZED VIEW cagg_view
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
Expand All @@ -384,6 +395,7 @@ CREATE TABLE cities(name text, currency text);
INSERT INTO cities VALUES ('Berlin', 'EUR'), ('London', 'PND');

--Error out when FROM clause has sub selects
\set ON_ERROR_STOP 0
CREATE MATERIALIZED VIEW conditions_summary_subselect
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
Expand Down Expand Up @@ -508,6 +520,15 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
FROM conditions FULL JOIN devices
ON conditions.device_id = devices.device_id
GROUP BY name, bucket;

CREATE MATERIALIZED VIEW cagg_right
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
AVG(temperature),
name
FROM conditions RIGHT JOIN devices
ON conditions.device_id = devices.device_id
GROUP BY name, bucket;
\set ON_ERROR_STOP 1

CREATE MATERIALIZED VIEW cagg_left_join
Expand All @@ -519,7 +540,7 @@ FROM conditions LEFT JOIN devices
ON conditions.device_id = devices.device_id
GROUP BY name, bucket;

--Error out for join between cagg and hypertable
-- Error out for join between cagg and hypertable
\set ON_ERROR_STOP 0
CREATE MATERIALIZED VIEW cagg_nested_ht
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
Expand All @@ -543,10 +564,12 @@ JOIN location ON location.name = devices.location
GROUP BY bucket, devices.name, location.name;

\set VERBOSITY terse
SET client_min_messages TO WARNING;
DROP TABLE conditions CASCADE;
DROP TABLE devices CASCADE;
DROP TABLE conditions_dup CASCADE;
DROP TABLE devices_dup CASCADE;
RESET client_min_messages;

\set VERBOSITY default

Expand Down Expand Up @@ -585,5 +608,7 @@ VACUUM ANALYZE;
SELECT a.* FROM cagg_realtime a WHERE a.location = 'Moscow' ORDER BY bucket LIMIT 2;

\set VERBOSITY terse
SET client_min_messages TO WARNING;
DROP TABLE conditions CASCADE;
DROP TABLE devices CASCADE;
RESET client_min_messages;

0 comments on commit d7fb0bd

Please sign in to comment.