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

Enable joins for hierarchical continuous aggregates #5344

Merged
merged 1 commit into from Mar 28, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
6 changes: 5 additions & 1 deletion CHANGELOG.md
Expand Up @@ -14,6 +14,7 @@ accidentally triggering the load of a previous DB version.**
* #5252 Improve unique constraint support on compressed hypertables
* #5312 Add timeout support to ping_data_node()
* #5454 Add support for ON CONFLICT DO UPDATE for compressed hypertables
* #5344 Enable JOINS for Hierarchical Continuous Aggregates

**Bugfixes**
* #5396 Fix SEGMENTBY columns predicates to be pushed down
Expand Down Expand Up @@ -46,7 +47,6 @@ We recommend that you upgrade at the next available opportunity.
* #5364 Fix num_chunks inconsistency in hypertables view
* #5367 Fix column name handling in old-style continuous aggregates
* #5378 Fix multinode DML HA performance regression
* #5384 Fix Hierarchical Continuous Aggregates chunk_interval_size
* #5304 Fix sub-second intervals in hierarchical caggs

**Thanks**
Expand Down Expand Up @@ -81,6 +81,10 @@ Sooner to that time, we will announce the specific version of TimescaleDB in whi
* #5246 Make connection establishment interruptible
* #5253 Make data node command execution interruptible
* #5262 Extend enabling compression on a continuous aggregrate with 'compress_segmentby' and 'compress_orderby' parameters
* #5343 Set PortalContext when starting job
* #5312 Add timeout support to the ping_data_node()
* #5212 Allow pushdown of reference table joins
* #5344 Enable JOINS for Hierarchical continuous aggregates
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I guess your CHANGELOG entry is on the wrong place, it should reside on the Unreleased section at the beginning of the file.


**Bugfixes**
* #4926 Fix corruption when inserting into compressed chunks
Expand Down
70 changes: 53 additions & 17 deletions tsl/src/continuous_aggs/create.c
Expand Up @@ -46,6 +46,7 @@
#include <parser/parse_oper.h>
#include <parser/parse_relation.h>
#include <parser/parse_type.h>
#include <parser/parsetree.h>
#include <rewrite/rewriteHandler.h>
#include <rewrite/rewriteManip.h>
#include <utils/acl.h>
Expand Down Expand Up @@ -1284,31 +1285,42 @@
op = (OpExpr *) join->quals;
rte = list_nth(query->rtable, ((RangeTblRef *) join->larg)->rtindex - 1);
rte_other = list_nth(query->rtable, ((RangeTblRef *) join->rarg)->rtindex - 1);
if (rte->subquery != NULL || rte_other->subquery != NULL)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("invalid continuous aggregate view"),
errdetail("sub-queries are not supported in FROM clause")));
RangeTblEntry *jrte = rt_fetch(join->rtindex, query->rtable);
if (jrte->joinaliasvars == NIL)
ereport(ERROR,

Check warning on line 1295 in tsl/src/continuous_aggs/create.c

View check run for this annotation

Codecov / codecov/patch

tsl/src/continuous_aggs/create.c#L1295

Added line #L1295 was not covered by tests
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("invalid continuous aggregate view")));
}
}
}

/*
* Cagg with joins does not support hierarchical caggs in from clause.
* Error out if there is aynthing else than one normal table and one hypertable
* in the from clause, e.g. sub-query, lateral, two hypertables, etc.
*/
if (rte->relkind == RELKIND_VIEW || rte_other->relkind == RELKIND_VIEW)
if (rte->lateral || rte_other->lateral)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("joins for hierarchical continuous aggregates are not supported")));

/*
* Error out if there is aynthing else than one normal table and one hypertable
* in the from clause, e.g. sub-query.
*/
if (((rte->relkind != RELKIND_RELATION && rte->relkind != RELKIND_VIEW) ||
rte->tablesample || rte->inh == false) ||
((rte_other->relkind != RELKIND_RELATION && rte_other->relkind != RELKIND_VIEW) ||
rte_other->tablesample || rte_other->inh == false) ||
errmsg("invalid continuous aggregate view"),
errdetail("lateral are not supported in FROM clause")));
if ((rte->relkind == RELKIND_VIEW && ts_is_hypertable(rte_other->relid)) ||
(rte_other->relkind == RELKIND_VIEW && ts_is_hypertable(rte->relid)))
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("invalid continuous aggregate view"),
errdetail("views are not supported in FROM clause")));
if (rte->relkind != RELKIND_VIEW && rte_other->relkind != RELKIND_VIEW &&
(ts_is_hypertable(rte->relid) == ts_is_hypertable(rte_other->relid)))
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("invalid continuous aggregate view"),
errdetail("from clause can only have one hypertable and one normal table")));
errdetail("multiple hypertables or normal tables"
" are not supported in FROM clause")));

/* Only inner joins are allowed. */
if (jointype != JOIN_INNER)
Expand Down Expand Up @@ -1340,7 +1352,12 @@
* that we know which one is hypertable to carry out the related
* processing in later parts of code.
*/
normal_table_id = ts_is_hypertable(rte->relid) ? rte_other->relid : rte->relid;
if (rte->relkind == RELKIND_VIEW)
normal_table_id = rte_other->relid;
else if (rte_other->relkind == RELKIND_VIEW)
normal_table_id = rte->relid;

Check warning on line 1358 in tsl/src/continuous_aggs/create.c

View check run for this annotation

Codecov / codecov/patch

tsl/src/continuous_aggs/create.c#L1358

Added line #L1358 was not covered by tests
else
normal_table_id = ts_is_hypertable(rte->relid) ? rte_other->relid : rte->relid;
if (normal_table_id == rte->relid)
rte = rte_other;
}
Expand Down Expand Up @@ -2450,14 +2467,28 @@
* which contains the information of the materialised hypertable
* that is created for this cagg.
*/
if (list_length(inp->final_userquery->jointree->fromlist) >= CONTINUOUS_AGG_MAX_JOIN_RELATIONS)
if (list_length(inp->final_userquery->jointree->fromlist) >=
CONTINUOUS_AGG_MAX_JOIN_RELATIONS ||
!IsA(linitial(inp->final_userquery->jointree->fromlist), RangeTblRef))
{
rte = makeNode(RangeTblEntry);
rte->alias = makeAlias(relname, NIL);
rte->inFromCl = true;
rte->inh = true;
rte->rellockmode = 1;
rte->eref = copyObject(rte->alias);
ListCell *l;
foreach (l, inp->final_userquery->jointree->fromlist)
{
Node *jtnode = (Node *) lfirst(l);
JoinExpr *join = NULL;
if (IsA(jtnode, JoinExpr))
{
join = castNode(JoinExpr, jtnode);
RangeTblEntry *jrte = rt_fetch(join->rtindex, inp->final_userquery->rtable);
rte->joinaliasvars = jrte->joinaliasvars;
}
}
Comment on lines +2481 to +2491
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Why this is needed?? Can u add a comment here. I also asked for the same in the other PR https://github.com/timescale/timescaledb/pull/5441/files#r1150565424

}
else
rte = llast_node(RangeTblEntry, inp->final_userquery->rtable);
Expand Down Expand Up @@ -3411,12 +3442,17 @@
*/
if (list_length(q2->rtable) == CONTINUOUS_AGG_MAX_JOIN_RELATIONS)
{
Oid normal_table_id = InvalidOid;
RangeTblRef *rtref = linitial_node(RangeTblRef, q2->jointree->fromlist);
RangeTblEntry *rte = list_nth(q2->rtable, rtref->rtindex - 1);
RangeTblRef *rtref_other = lsecond_node(RangeTblRef, q2->jointree->fromlist);
RangeTblEntry *rte_other = list_nth(q2->rtable, rtref_other->rtindex - 1);

Oid normal_table_id = ts_is_hypertable(rte->relid) ? rte_other->relid : rte->relid;
if (rte->relkind == RELKIND_VIEW)
normal_table_id = rte_other->relid;
else if (rte_other->relkind == RELKIND_VIEW)
normal_table_id = rte->relid;

Check warning on line 3453 in tsl/src/continuous_aggs/create.c

View check run for this annotation

Codecov / codecov/patch

tsl/src/continuous_aggs/create.c#L3453

Added line #L3453 was not covered by tests
else
normal_table_id = ts_is_hypertable(rte->relid) ? rte_other->relid : rte->relid;
if (normal_table_id == rte->relid)
varno = 2;
else
Expand Down
40 changes: 24 additions & 16 deletions tsl/test/expected/cagg_joins-12.out
Expand Up @@ -193,10 +193,11 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
AVG(temperature),
MAX(temperature),
MIN(temperature),
name
name,
devices.device_id AS thermo_id
FROM conditions, devices
WHERE conditions.device_id = devices.device_id
GROUP BY name, bucket;
GROUP BY name, bucket, thermo_id;
NOTICE: refreshing continuous aggregate "conditions_summary_daily"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
CREATE MATERIALIZED VIEW conditions_summary_daily_reorder
Expand Down Expand Up @@ -297,7 +298,7 @@ select temperature, count(*) from conditions,
LATERAL (Select * from mat_t1 where a = conditions.temperature) q
group by temperature WITH NO DATA;
ERROR: invalid continuous aggregate view
DETAIL: from clause can only have one hypertable and one normal table
DETAIL: lateral are not supported in FROM clause
--Error out if from clause has view
CREATE MATERIALIZED VIEW conditions_summary_daily_view
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
Expand All @@ -310,13 +311,15 @@ 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: joins for hierarchical continuous aggregates are not supported
ERROR: invalid continuous aggregate view
DETAIL: views are not supported in FROM clause
-- Nested CAgg over a CAgg with join
CREATE MATERIALIZED VIEW cagg_on_cagg
WITH (timescaledb.continuous, timescaledb.materialized_only=true) AS
SELECT time_bucket(INTERVAL '1 day', bucket) AS bucket,
SUM(avg) AS temperature
FROM conditions_summary_daily
FROM conditions_summary_daily, devices
WHERE devices.device_id = conditions_summary_daily.thermo_id
GROUP BY 1;
NOTICE: refreshing continuous aggregate "cagg_on_cagg"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
Expand All @@ -337,7 +340,7 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
FROM conditions JOIN (SELECT * FROM devices WHERE location in (SELECT name from cities where currency = 'EUR')) dev ON conditions.device_id = dev.device_id
GROUP BY name, bucket;
ERROR: invalid continuous aggregate view
DETAIL: from clause can only have one hypertable and one normal table
DETAIL: sub-queries are not supported in FROM clause
DROP TABLE cities CASCADE;
--Error out when join is between two hypertables
CREATE MATERIALIZED VIEW conditions_summary_daily_ht
Expand All @@ -350,7 +353,7 @@ FROM conditions, conditions_dup
WHERE conditions.device_id = conditions_dup.device_id
GROUP BY bucket;
ERROR: invalid continuous aggregate view
DETAIL: from clause can only have one hypertable and one normal table
DETAIL: multiple hypertables or normal tables are not supported in FROM clause
--Error out when join is between two normal tables
CREATE MATERIALIZED VIEW conditions_summary_daily_nt
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
Expand All @@ -363,7 +366,7 @@ FROM devices, devices_dup
WHERE devices.device_id = devices_dup.device_id
GROUP BY devices.name, devices.location;
ERROR: invalid continuous aggregate view
DETAIL: from clause can only have one hypertable and one normal table
DETAIL: multiple hypertables or normal tables are not supported in FROM clause
--Error out when join is on non-equality condition
CREATE MATERIALIZED VIEW conditions_summary_daily_unequal
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
Expand Down Expand Up @@ -432,25 +435,27 @@ WHERE conditions.device_id = devices.device_id
GROUP BY name, bucket, devices.device_id;
NOTICE: refreshing continuous aggregate "conditions_summary_daily_cagg"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
--Errors out for join between cagg and normal table
--Join between cagg and normal table
CREATE MATERIALIZED VIEW conditions_summary_daily_nested
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
SELECT time_bucket(INTERVAL '1 day', cagg.bucket) AS bucket,
devices.name
FROM conditions_summary_daily_cagg cagg, devices
WHERE cagg.device_id = devices.device_id
GROUP BY devices.name, bucket;
ERROR: joins for hierarchical continuous aggregates are not supported
GROUP BY 1,2;
NOTICE: refreshing continuous aggregate "conditions_summary_daily_nested"
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
CREATE MATERIALIZED VIEW conditions_summary_daily_nested
CREATE MATERIALIZED VIEW conditions_summary_daily_nested_ht
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
SELECT time_bucket(INTERVAL '1 day', cagg.bucket) AS bucket,
cagg.name,
conditions.temperature
FROM conditions_summary_daily_cagg cagg, conditions
WHERE cagg.device_id = conditions.device_id
GROUP BY conditions.temperature, bucket, cagg.name;
ERROR: joins for hierarchical continuous aggregates are not supported
GROUP BY 1,2,3;
ERROR: invalid continuous aggregate view
DETAIL: views are not supported in FROM clause
\set VERBOSITY terse
DROP TABLE conditions CASCADE;
NOTICE: drop cascades to 15 other objects
Expand All @@ -459,8 +464,11 @@ 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
ERROR: cannot drop view conditions_summary_daily_cagg because other objects depend on it
DROP TABLE devices CASCADE;
NOTICE: drop cascades to view devices_view
NOTICE: drop cascades to 18 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
ERROR: cannot drop the partial/direct view because it is required by a continuous aggregate
DROP TABLE conditions_dup CASCADE;
DROP TABLE devices_dup CASCADE;
40 changes: 24 additions & 16 deletions tsl/test/expected/cagg_joins-13.out
Expand Up @@ -193,10 +193,11 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
AVG(temperature),
MAX(temperature),
MIN(temperature),
name
name,
devices.device_id AS thermo_id
FROM conditions, devices
WHERE conditions.device_id = devices.device_id
GROUP BY name, bucket;
GROUP BY name, bucket, thermo_id;
NOTICE: refreshing continuous aggregate "conditions_summary_daily"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
CREATE MATERIALIZED VIEW conditions_summary_daily_reorder
Expand Down Expand Up @@ -298,7 +299,7 @@ select temperature, count(*) from conditions,
LATERAL (Select * from mat_t1 where a = conditions.temperature) q
group by temperature WITH NO DATA;
ERROR: invalid continuous aggregate view
DETAIL: from clause can only have one hypertable and one normal table
DETAIL: lateral are not supported in FROM clause
--Error out if from clause has view
CREATE MATERIALIZED VIEW conditions_summary_daily_view
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
Expand All @@ -311,13 +312,15 @@ 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: joins for hierarchical continuous aggregates are not supported
ERROR: invalid continuous aggregate view
DETAIL: views are not supported in FROM clause
-- Nested CAgg over a CAgg with join
CREATE MATERIALIZED VIEW cagg_on_cagg
WITH (timescaledb.continuous, timescaledb.materialized_only=true) AS
SELECT time_bucket(INTERVAL '1 day', bucket) AS bucket,
SUM(avg) AS temperature
FROM conditions_summary_daily
FROM conditions_summary_daily, devices
WHERE devices.device_id = conditions_summary_daily.thermo_id
GROUP BY 1;
NOTICE: refreshing continuous aggregate "cagg_on_cagg"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
Expand All @@ -338,7 +341,7 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket,
FROM conditions JOIN (SELECT * FROM devices WHERE location in (SELECT name from cities where currency = 'EUR')) dev ON conditions.device_id = dev.device_id
GROUP BY name, bucket;
ERROR: invalid continuous aggregate view
DETAIL: from clause can only have one hypertable and one normal table
DETAIL: sub-queries are not supported in FROM clause
DROP TABLE cities CASCADE;
--Error out when join is between two hypertables
CREATE MATERIALIZED VIEW conditions_summary_daily_ht
Expand All @@ -351,7 +354,7 @@ FROM conditions, conditions_dup
WHERE conditions.device_id = conditions_dup.device_id
GROUP BY bucket;
ERROR: invalid continuous aggregate view
DETAIL: from clause can only have one hypertable and one normal table
DETAIL: multiple hypertables or normal tables are not supported in FROM clause
--Error out when join is between two normal tables
CREATE MATERIALIZED VIEW conditions_summary_daily_nt
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
Expand All @@ -364,7 +367,7 @@ FROM devices, devices_dup
WHERE devices.device_id = devices_dup.device_id
GROUP BY devices.name, devices.location;
ERROR: invalid continuous aggregate view
DETAIL: from clause can only have one hypertable and one normal table
DETAIL: multiple hypertables or normal tables are not supported in FROM clause
--Error out when join is on non-equality condition
CREATE MATERIALIZED VIEW conditions_summary_daily_unequal
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
Expand Down Expand Up @@ -433,25 +436,27 @@ WHERE conditions.device_id = devices.device_id
GROUP BY name, bucket, devices.device_id;
NOTICE: refreshing continuous aggregate "conditions_summary_daily_cagg"
HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation.
--Errors out for join between cagg and normal table
--Join between cagg and normal table
CREATE MATERIALIZED VIEW conditions_summary_daily_nested
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
SELECT time_bucket(INTERVAL '1 day', cagg.bucket) AS bucket,
devices.name
FROM conditions_summary_daily_cagg cagg, devices
WHERE cagg.device_id = devices.device_id
GROUP BY devices.name, bucket;
ERROR: joins for hierarchical continuous aggregates are not supported
GROUP BY 1,2;
NOTICE: refreshing continuous aggregate "conditions_summary_daily_nested"
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
CREATE MATERIALIZED VIEW conditions_summary_daily_nested
CREATE MATERIALIZED VIEW conditions_summary_daily_nested_ht
WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS
SELECT time_bucket(INTERVAL '1 day', cagg.bucket) AS bucket,
cagg.name,
conditions.temperature
FROM conditions_summary_daily_cagg cagg, conditions
WHERE cagg.device_id = conditions.device_id
GROUP BY conditions.temperature, bucket, cagg.name;
ERROR: joins for hierarchical continuous aggregates are not supported
GROUP BY 1,2,3;
ERROR: invalid continuous aggregate view
DETAIL: views are not supported in FROM clause
\set VERBOSITY terse
DROP TABLE conditions CASCADE;
NOTICE: drop cascades to 24 other objects
Expand All @@ -463,8 +468,11 @@ 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
ERROR: cannot drop view conditions_summary_daily_cagg because other objects depend on it
DROP TABLE devices CASCADE;
NOTICE: drop cascades to view devices_view
NOTICE: drop cascades to 27 other objects
NOTICE: drop cascades to 2 other objects
NOTICE: drop cascades to 2 other objects
ERROR: cannot drop the partial/direct view because it is required by a continuous aggregate
DROP TABLE conditions_dup CASCADE;
DROP TABLE devices_dup CASCADE;