From 23ba4e07dab36525dfb27539dc5c45b531a850ca Mon Sep 17 00:00:00 2001 From: Rafia Sabih Date: Tue, 14 Mar 2023 16:37:02 +0100 Subject: [PATCH] Pass join related structs to the cagg rte In case of joins in the continuous aggregates, pass the required structs to the new rte created. These values are required by the planner to finally query the materialized view. Fixes #5433 --- CHANGELOG.md | 2 + scripts/test_updates_pg13.sh | 5 +- scripts/test_updates_pg14.sh | 6 +- scripts/test_updates_pg15.sh | 6 +- sql/updates/post-update.sql | 31 ++- test/sql/updates/post.repair.cagg_joins.sql | 24 ++ test/sql/updates/post.repair.sql | 23 +- test/sql/updates/setup.repair.cagg_joins.sql | 90 ++++++ test/sql/updates/setup.repair.sql | 14 + tsl/src/continuous_aggs/create.c | 186 ++++++++++--- tsl/test/expected/cagg_joins-12.out | 209 +++++++++++++- tsl/test/expected/cagg_joins-13.out | 278 ++++++++++++++++++- tsl/test/expected/cagg_joins-14.out | 278 ++++++++++++++++++- tsl/test/expected/cagg_joins-15.out | 278 ++++++++++++++++++- tsl/test/sql/cagg_joins.sql.in | 83 +++++- 15 files changed, 1426 insertions(+), 87 deletions(-) create mode 100644 test/sql/updates/post.repair.cagg_joins.sql create mode 100644 test/sql/updates/setup.repair.cagg_joins.sql diff --git a/CHANGELOG.md b/CHANGELOG.md index ec4782126ba..6790f8d2653 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -33,12 +33,14 @@ accidentally triggering the load of a previous DB version.** * #5497 Allow named time_bucket arguments in Cagg definition * #5499 Do not segfault on large histogram() parameters * #5500 Fix when no FROM clause in continuous aggregate definition +* #5433 Fix join rte in CAggs with joins **Thanks** * @nikolaps for reporting an issue with the COPY fetcher * @S-imo-n for reporting the issue on Background Worker Scheduler crash * @kovetskiy and @DZDomi for reporting peformance regression in Realtime Continuous Aggregates * @geezhu for reporting issue on segfault in historgram() +* @mwahlthuetter for reporting the issue with joins in CAggs ## 2.10.1 (2023-03-07) diff --git a/scripts/test_updates_pg13.sh b/scripts/test_updates_pg13.sh index 76189be0455..ebd4aaf5fb1 100755 --- a/scripts/test_updates_pg13.sh +++ b/scripts/test_updates_pg13.sh @@ -12,5 +12,8 @@ run_tests "$@" -v7 \ 2.4.0-pg13 2.4.1-pg13 2.4.2-pg13 run_tests "$@" -v8 \ 2.5.0-pg13 2.5.1-pg13 2.5.2-pg13 2.6.0-pg13 2.6.1-pg13 2.7.0-pg13 2.7.1-pg13 2.7.2-pg13 \ - 2.8.0-pg13 2.8.1-pg13 2.9.0-pg13 2.9.1-pg13 2.9.2-pg13 2.9.3-pg13 2.10.0-pg13 2.10.1-pg13 + 2.8.0-pg13 2.8.1-pg13 2.9.0-pg13 2.9.1-pg13 2.9.2-pg13 2.9.3-pg13 +# Also run repair tests for >=2.10.x versions due to PR #5441 +run_tests "$@" -r -v8 \ + 2.10.0-pg13 2.10.1-pg13 diff --git a/scripts/test_updates_pg14.sh b/scripts/test_updates_pg14.sh index 5534f6252b6..303a1c5c19f 100755 --- a/scripts/test_updates_pg14.sh +++ b/scripts/test_updates_pg14.sh @@ -11,5 +11,9 @@ run_tests "$@" -v7 \ 2.5.0-pg14 2.5.1-pg14 run_tests "$@" -v8 \ 2.5.0-pg14 2.5.1-pg14 2.5.2-pg14 2.6.0-pg14 2.6.1-pg14 2.7.0-pg14 2.7.1-pg14 2.7.2-pg14 \ - 2.8.0-pg14 2.8.1-pg14 2.9.0-pg14 2.9.1-pg14 2.9.2-pg14 2.9.3-pg14 2.10.0-pg14 2.10.1-pg14 + 2.8.0-pg14 2.8.1-pg14 2.9.0-pg14 2.9.1-pg14 2.9.2-pg14 2.9.3-pg14 + +# Also run repair tests for >=2.10.x versions due to PR #5441 +run_tests "$@" -r -v8 \ + 2.10.0-pg14 2.10.1-pg14 diff --git a/scripts/test_updates_pg15.sh b/scripts/test_updates_pg15.sh index 256840769c2..115c8a319e1 100755 --- a/scripts/test_updates_pg15.sh +++ b/scripts/test_updates_pg15.sh @@ -8,4 +8,8 @@ SCRIPT_DIR=$(dirname $0) source ${SCRIPT_DIR}/test_functions.inc run_tests "$@" -v8 \ - 2.9.0-pg15 2.9.1-pg15 2.9.2-pg15 2.9.3-pg15 2.10.0-pg15 2.10.1-pg15 + 2.9.0-pg15 2.9.1-pg15 2.9.2-pg15 2.9.3-pg15 + +# Also run repair tests for >=2.10.x versions due to PR #5441 +run_tests "$@" -r -v8 \ + 2.10.0-pg15 2.10.1-pg15 diff --git a/sql/updates/post-update.sql b/sql/updates/post-update.sql index 2c9ea48c323..6ced0df1a85 100644 --- a/sql/updates/post-update.sql +++ b/sql/updates/post-update.sql @@ -8,7 +8,7 @@ BEGIN SELECT extversion INTO ts_version FROM pg_extension WHERE extname = 'timescaledb'; IF ts_version >= '2.7.0' THEN CREATE PROCEDURE _timescaledb_internal.post_update_cagg_try_repair( - cagg_view REGCLASS + cagg_view REGCLASS, force_rebuild boolean ) AS '@MODULE_PATHNAME@', 'ts_cagg_try_repair' LANGUAGE C; END IF; FOR vname, materialized_only IN select format('%I.%I', cagg.user_view_schema, cagg.user_view_name)::regclass, cagg.materialized_only from _timescaledb_catalog.continuous_agg cagg @@ -26,7 +26,7 @@ BEGIN EXECUTE format('ALTER MATERIALIZED VIEW %s SET (timescaledb.materialized_only=%L) ', vname::text, materialized_only); ELSE SET log_error_verbosity TO VERBOSE; - CALL _timescaledb_internal.post_update_cagg_try_repair(vname); + CALL _timescaledb_internal.post_update_cagg_try_repair(vname, false); END IF; END LOOP; IF ts_version >= '2.7.0' THEN @@ -36,6 +36,33 @@ BEGIN END $$; +-- For tsdb >= v2.10.0 apply the cagg repair when necessary +DO $$ +DECLARE + vname regclass; + materialized_only bool; + ts_version TEXT; +BEGIN + SELECT extversion INTO ts_version FROM pg_extension WHERE extname = 'timescaledb'; + IF ts_version >= '2.10.0' THEN + CREATE PROCEDURE _timescaledb_internal.post_update_cagg_try_repair( + cagg_view REGCLASS, force_rebuild BOOLEAN + ) AS '@MODULE_PATHNAME@', 'ts_cagg_try_repair' LANGUAGE C; + + FOR vname, materialized_only IN select format('%I.%I', cagg.user_view_schema, cagg.user_view_name)::regclass, cagg.materialized_only from _timescaledb_catalog.continuous_agg cagg + LOOP + IF ts_version >= '2.10.0' THEN + SET log_error_verbosity TO VERBOSE; + CALL _timescaledb_internal.post_update_cagg_try_repair(vname, true); + END IF; + END LOOP; + + DROP PROCEDURE IF EXISTS _timescaledb_internal.post_update_cagg_try_repair(REGCLASS, BOOLEAN); + END IF; + EXCEPTION WHEN OTHERS THEN RAISE; +END +$$; + -- can only be dropped after views have been rebuilt DROP FUNCTION IF EXISTS _timescaledb_internal.cagg_watermark(oid); diff --git a/test/sql/updates/post.repair.cagg_joins.sql b/test/sql/updates/post.repair.cagg_joins.sql new file mode 100644 index 00000000000..5a134c96127 --- /dev/null +++ b/test/sql/updates/post.repair.cagg_joins.sql @@ -0,0 +1,24 @@ +-- This file and its contents are licensed under the Apache License 2.0. +-- Please see the included NOTICE for copyright information and +-- LICENSE-APACHE for a copy of the license. + +SELECT current_setting('server_version_num')::int >= 130000 AS has_cagg_join_using \gset + +\d+ cagg_joins_upgrade_test_with_realtime +SELECT * FROM cagg_joins_upgrade_test_with_realtime ORDER BY bucket; + +\d+ cagg_joins_upgrade_test +SELECT * FROM cagg_joins_upgrade_test ORDER BY bucket; + +\d+ cagg_joins_where +SELECT * FROM cagg_joins_where ORDER BY bucket; + +\if :has_cagg_join_using + \d+ cagg_joins_upgrade_test_with_realtime_using + SELECT * FROM cagg_joins_upgrade_test_with_realtime_using ORDER BY bucket; + + \d+ cagg_joins_upgrade_test_using + SELECT * FROM cagg_joins_upgrade_test_using ORDER BY bucket; + +\endif + diff --git a/test/sql/updates/post.repair.sql b/test/sql/updates/post.repair.sql index d95e294aa60..2075442ed18 100644 --- a/test/sql/updates/post.repair.sql +++ b/test/sql/updates/post.repair.sql @@ -2,9 +2,26 @@ -- Please see the included NOTICE for copyright information and -- LICENSE-APACHE for a copy of the license. --- Re-add the dropped foreign key constraint that was dropped for --- repair testing. -ALTER TABLE _timescaledb_catalog.chunk_constraint +SELECT extversion < '2.10.0' AS test_repair_dimension +FROM pg_extension +WHERE extname = 'timescaledb' \gset + +SELECT extversion >= '2.10.0' AS has_cagg_joins +FROM pg_extension +WHERE extname = 'timescaledb' \gset + +SELECT :'TEST_VERSION' >= 'v8' AS is_GTE_v8 \gset + +\if :test_repair_dimension + -- Re-add the dropped foreign key constraint that was dropped for + -- repair testing. + ALTER TABLE _timescaledb_catalog.chunk_constraint ADD CONSTRAINT chunk_constraint_dimension_slice_id_fkey FOREIGN KEY (dimension_slice_id) REFERENCES _timescaledb_catalog.dimension_slice (id); +\endif + +\if :has_cagg_joins AND :is_GTE_v8 +--Check if the repaired cagg with joins work alright now +\ir post.repair.cagg_joins.sql +\endif diff --git a/test/sql/updates/setup.repair.cagg_joins.sql b/test/sql/updates/setup.repair.cagg_joins.sql new file mode 100644 index 00000000000..9657184c693 --- /dev/null +++ b/test/sql/updates/setup.repair.cagg_joins.sql @@ -0,0 +1,90 @@ +-- This file and its contents are licensed under the Apache License 2.0. +-- Please see the included NOTICE for copyright information and +-- LICENSE-APACHE for a copy of the license. + +SELECT current_setting('server_version_num')::int >= 130000 AS has_cagg_join_using \gset + +CREATE TABLE ht_cagg_joins( + day TIMESTAMPTZ NOT NULL, + city text NOT NULL, + temperature INT NOT NULL, +device_id int NOT NULL); +SELECT create_hypertable( + 'ht_cagg_joins', 'day', + chunk_time_interval => INTERVAL '1 day' +); +INSERT INTO ht_cagg_joins (day, city, temperature, device_id) VALUES + ('2021-06-14 00:00:00-00'::timestamptz, 'Moscow', 26,1), + ('2021-06-15 00:00:00-00'::timestamptz, 'Moscow', 22,2), + ('2021-06-16 00:00:00-00'::timestamptz, 'Berlin', 24,3), + ('2021-06-17 00:00:00-00'::timestamptz, 'London', 24,4), + ('2021-06-18 00:00:00-00'::timestamptz, 'Stockholm', 27,4), + ('2021-06-19 00:00:00-00'::timestamptz, 'Moscow', 28,4), + ('2021-06-20 00:00:00-00'::timestamptz, 'Stockholm', 30,1), + ('2021-06-21 00:00:00-00'::timestamptz, 'London', 31,1), + ('2021-06-22 00:00:00-00'::timestamptz, 'Stockholm', 34,1), + ('2021-06-23 00:00:00-00'::timestamptz, 'Moscow', 34,2), + ('2021-06-24 00:00:00-00'::timestamptz, 'London', 34,2), + ('2021-06-25 00:00:00-00'::timestamptz, 'Stockholm', 32,3), + ('2021-06-26 00:00:00-00'::timestamptz, 'Berlin', 32,3), + ('2021-06-27 00:00:00-00'::timestamptz, 'Stockholm', 31,3); + +CREATE TABLE nt_cagg_joins ( device_id int not null, name text, location text); +INSERT INTO nt_cagg_joins values (1, 'thermo_1', 'Moscow'), (2, 'thermo_2', 'Berlin'),(3, 'thermo_3', 'London'),(4, 'thermo_4', 'Stockholm'); + +--Create a cagg with join between a hypertable and a normal table +-- with equality condition on inner join type and realtime aggregation enabled +CREATE MATERIALIZED VIEW cagg_joins_upgrade_test_with_realtime +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + name +FROM ht_cagg_joins JOIN nt_cagg_joins +ON ht_cagg_joins.device_id = nt_cagg_joins.device_id +GROUP BY 1,3; + +--Create a cagg with join between a hypertable and a normal table +-- with equality condition on inner join type and realtime aggregation disabled +CREATE MATERIALIZED VIEW cagg_joins_upgrade_test +WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + name +FROM ht_cagg_joins JOIN nt_cagg_joins +ON ht_cagg_joins.device_id = nt_cagg_joins.device_id +GROUP BY 1,3; + +--Create a Cagg with JOIN and additional WHERE conditions +CREATE MATERIALIZED VIEW cagg_joins_where +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + name +FROM ht_cagg_joins JOIN nt_cagg_joins +ON ht_cagg_joins.device_id = nt_cagg_joins.device_id +WHERE ht_cagg_joins.city = nt_cagg_joins.location +GROUP BY 1,3; + +-- Only test joins with using clause for postgresql versions above 12 +\if :has_cagg_join_using + --Create a cagg with join with using clause and realtime aggregation enabled + CREATE MATERIALIZED VIEW cagg_joins_upgrade_test_with_realtime_using + WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS + SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + name + FROM ht_cagg_joins JOIN nt_cagg_joins + USING (device_id) + GROUP BY 1,3; + + --Create a cagg with join with using and realtime aggregation disabled + CREATE MATERIALIZED VIEW cagg_joins_upgrade_test_using + WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS + SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + name + FROM ht_cagg_joins JOIN nt_cagg_joins + USING (device_id) + GROUP BY 1,3; + +\endif diff --git a/test/sql/updates/setup.repair.sql b/test/sql/updates/setup.repair.sql index ba8d77d245c..738d465e4ad 100644 --- a/test/sql/updates/setup.repair.sql +++ b/test/sql/updates/setup.repair.sql @@ -7,6 +7,14 @@ -- the dimension slice table. The repair script should then repair all -- of them and there should be no dimension slices missing. +SELECT extversion < '2.10.0' AS test_repair_dimension +FROM pg_extension +WHERE extname = 'timescaledb' \gset + +SELECT extversion >= '2.10.0' AS has_cagg_joins +FROM pg_extension +WHERE extname = 'timescaledb' \gset + CREATE TABLE repair_test_int(time integer not null, temp float8, tag integer, color integer); CREATE TABLE repair_test_timestamptz(time timestamptz not null, temp float8, tag integer, color integer); CREATE TABLE repair_test_extra(time timestamptz not null, temp float8, tag integer, color integer); @@ -80,6 +88,7 @@ CREATE VIEW slices AS ( ON di.hypertable_id = ch.hypertable_id AND attname = di.column_name ); +\if :test_repair_dimension -- Break the first time dimension on each table. These are different -- depending on the time type for the table and we need to check all -- versions. @@ -177,5 +186,10 @@ SELECT DISTINCT WHERE dimension_slice_id NOT IN (SELECT id FROM _timescaledb_catalog.dimension_slice); DROP VIEW slices; +\endif \ir setup.repair.cagg.sql + +\if :has_cagg_joins + \ir setup.repair.cagg_joins.sql +\endif diff --git a/tsl/src/continuous_aggs/create.c b/tsl/src/continuous_aggs/create.c index 8ea6714b3b2..1d9b84fe1af 100644 --- a/tsl/src/continuous_aggs/create.c +++ b/tsl/src/continuous_aggs/create.c @@ -2477,7 +2477,7 @@ finalizequery_init(FinalizeQueryInfo *inp, Query *orig_query, MatTableColumnInfo * This is the function responsible for creating the final * structures for selecting from the materialized hypertable * created for the Cagg which is - * select * from _timescaldeb_internal._matrialized_hypertable_ + * select * from _timescaldeb_internal._materialized_hypertable_ */ static Query * finalizequery_get_select_query(FinalizeQueryInfo *inp, List *matcollist, @@ -2509,6 +2509,9 @@ finalizequery_get_select_query(FinalizeQueryInfo *inp, List *matcollist, ListCell *l; foreach (l, inp->final_userquery->jointree->fromlist) { + /* + * In case of joins, update the rte with all the join related struct. + */ Node *jtnode = (Node *) lfirst(l); JoinExpr *join = NULL; if (IsA(jtnode, JoinExpr)) @@ -2516,26 +2519,47 @@ finalizequery_get_select_query(FinalizeQueryInfo *inp, List *matcollist, join = castNode(JoinExpr, jtnode); RangeTblEntry *jrte = rt_fetch(join->rtindex, inp->final_userquery->rtable); rte->joinaliasvars = jrte->joinaliasvars; + rte->jointype = jrte->jointype; +#if PG13_GE + rte->joinleftcols = jrte->joinleftcols; + rte->joinrightcols = jrte->joinrightcols; + rte->joinmergedcols = jrte->joinmergedcols; +#endif +#if PG14_GE + rte->join_using_alias = jrte->join_using_alias; +#endif + rte->selectedCols = jrte->selectedCols; } } } else + { rte = llast_node(RangeTblEntry, inp->final_userquery->rtable); + rte->eref->colnames = NIL; + rte->selectedCols = NULL; + } + if (rte->eref->colnames == NIL) + { + /* + * We only need to do this for the case when there is no Join node in the query. + * In the case of join, rte->eref is already populated by jrte->eref and hence the + * relevant info, so need not to do this. + */ + + /* Aliases for column names for the materialization table. */ + foreach (lc, matcollist) + { + ColumnDef *cdef = lfirst_node(ColumnDef, lc); + rte->eref->colnames = lappend(rte->eref->colnames, makeString(cdef->colname)); + rte->selectedCols = bms_add_member(rte->selectedCols, + list_length(rte->eref->colnames) - + FirstLowInvalidHeapAttributeNumber); + } + } rte->relid = mattbladdress->objectId; rte->rtekind = RTE_RELATION; rte->relkind = RELKIND_RELATION; rte->tablesample = NULL; - rte->eref->colnames = NIL; - rte->selectedCols = NULL; - /* Aliases for column names for the materialization table. */ - foreach (lc, matcollist) - { - ColumnDef *cdef = (ColumnDef *) lfirst(lc); - rte->eref->colnames = lappend(rte->eref->colnames, makeString(cdef->colname)); - rte->selectedCols = - bms_add_member(rte->selectedCols, - list_length(rte->eref->colnames) - FirstLowInvalidHeapAttributeNumber); - } rte->requiredPerms |= ACL_SELECT; rte->insertedCols = NULL; rte->updatedCols = NULL; @@ -2544,7 +2568,13 @@ finalizequery_get_select_query(FinalizeQueryInfo *inp, List *matcollist, foreach (lc, inp->final_seltlist) { TargetEntry *tle = (TargetEntry *) lfirst(lc); - if (IsA(tle->expr, Var)) + /* + * In case when this is a cagg wth joins, the Var from the normal table + * already has resorigtbl populated and we need to use that to resolve + * the Var. Hence only modify the tle when resorigtbl is unset + * which means it is Var of the Hypertable + */ + if (IsA(tle->expr, Var) && !OidIsValid(tle->resorigtbl)) { tle->resorigtbl = rte->relid; tle->resorigcol = ((Var *) tle->expr)->varattno; @@ -2553,7 +2583,9 @@ finalizequery_get_select_query(FinalizeQueryInfo *inp, List *matcollist, CAGG_MAKEQUERY(final_selquery, inp->final_userquery); final_selquery->hasAggs = !inp->finalized; - 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)) { RangeTblRef *rtr; final_selquery->rtable = list_make1(rte); @@ -2971,7 +3003,7 @@ remove_old_and_new_rte_from_query(Query *query) * for errors and attempt to rebuild it if required. */ static void -cagg_rebuild_view_definition(ContinuousAgg *agg, Hypertable *mat_ht) +cagg_rebuild_view_definition(ContinuousAgg *agg, Hypertable *mat_ht, bool force_rebuild) { bool test_failed = false; char *relname = agg->data.user_view_name.data; @@ -2979,27 +3011,75 @@ cagg_rebuild_view_definition(ContinuousAgg *agg, Hypertable *mat_ht) ListCell *lc1, *lc2; int sec_ctx; Oid uid, saved_uid; + RangeTblRef *rtref = NULL; + RangeTblEntry *rte = NULL; + Query *subquery = NULL; + /* Cagg view created by the user. */ Oid user_view_oid = relation_oid(agg->data.user_view_schema, agg->data.user_view_name); Relation user_view_rel = relation_open(user_view_oid, AccessShareLock); Query *user_query = get_view_query(user_view_rel); + bool finalized = ContinuousAggIsFinalized(agg); + bool has_joins = false; /* Extract final query from user view query. */ Query *final_query = copyObject(user_query); remove_old_and_new_rte_from_query(final_query); - if (!agg->data.materialized_only) + + if (finalized && !force_rebuild) { - final_query = destroy_union_query(final_query); + /* This continuous aggregate does not have partials, do not check for defects. */ + relation_close(user_view_rel, NoLock); + return; } - if (finalized) + /* + * If there is a join in CAggs then rebuild it definitley, + * because v 2.10.0 has created the definition with missing structs. + */ + if (final_query->jointree && final_query->jointree->fromlist) { - /* This continuous aggregate does not have partials, do not check for defects. */ + ListCell *l; + foreach (l, final_query->jointree->fromlist) + { + Node *jtnode = (Node *) lfirst(l); + if (IsA(jtnode, JoinExpr)) + has_joins = true; + } + } + else + { + /* + * In case of caggs with join and realtime aggregate enabled, + * the actual stuff is in subquery. Check how the union query is + * build in build_union_query. + */ + rtref = linitial_node(RangeTblRef, final_query->rtable); + rte = list_nth(final_query->rtable, rtref->rtindex - 1); + subquery = castNode(Query, rte->subquery); + if (subquery->jointree && subquery->jointree->fromlist) + { + ListCell *l; + foreach (l, subquery->jointree->fromlist) + { + Node *jtnode = (Node *) lfirst(l); + if (IsA(jtnode, JoinExpr)) + has_joins = true; + } + } + } + if (!has_joins && !finalized) + { + /* No joins in Cagg, no need to rebuild for this case */ relation_close(user_view_rel, NoLock); return; } + if (!agg->data.materialized_only) + { + final_query = destroy_union_query(final_query); + } FinalizeQueryInfo fqi; MatTableColumnInfo mattblinfo; ObjectAddress mataddress = { @@ -3021,17 +3101,33 @@ cagg_rebuild_view_definition(ContinuousAgg *agg, Hypertable *mat_ht) fqi.finalized = finalized; finalizequery_init(&fqi, direct_query, &mattblinfo); - mattablecolumninfo_addinternal(&mattblinfo); + /* + * Add any internal columns needed for materialization based + * on the user query's table. + */ + if (!finalized) + mattablecolumninfo_addinternal(&mattblinfo); - Query *view_query = - finalizequery_get_select_query(&fqi, mattblinfo.matcollist, &mataddress, relname); + Query *view_query = NULL; + if (has_joins) + { + view_query = finalizequery_get_select_query(&fqi, + mattblinfo.matcollist, + &mataddress, + NameStr(mat_ht->fd.table_name)); + } + else + view_query = + finalizequery_get_select_query(&fqi, mattblinfo.matcollist, &mataddress, relname); if (!agg->data.materialized_only) + { view_query = build_union_query(&timebucket_exprinfo, mattblinfo.matpartcolno, view_query, direct_query, mat_ht->fd.id); + } if (list_length(mattblinfo.matcollist) != ts_get_relnatts(mat_ht->main_table_relid)) /* @@ -3041,7 +3137,6 @@ cagg_rebuild_view_definition(ContinuousAgg *agg, Hypertable *mat_ht) * rebuild those views since the materialization table can not be queried correctly. */ test_failed = true; - /* * When calling StoreViewQuery the target list names of the query have to * match the view's tuple descriptor attribute names. But if a column of the continuous @@ -3106,6 +3201,7 @@ tsl_cagg_try_repair(PG_FUNCTION_ARGS) { Oid relid = PG_ARGISNULL(0) ? InvalidOid : PG_GETARG_OID(0); char relkind = get_rel_relkind(relid); + bool force_rebuild = PG_ARGISNULL(0) ? false : PG_GETARG_BOOL(1); ContinuousAgg *cagg = NULL; if (RELKIND_VIEW == relkind) @@ -3123,14 +3219,12 @@ tsl_cagg_try_repair(PG_FUNCTION_ARGS) Hypertable *mat_ht = ts_hypertable_cache_get_entry_by_id(hcache, cagg->data.mat_hypertable_id); Assert(mat_ht != NULL); - - cagg_rebuild_view_definition(cagg, mat_ht); + cagg_rebuild_view_definition(cagg, mat_ht, force_rebuild); ts_cache_release(hcache); PG_RETURN_VOID(); } - /* * Flip the view definition of an existing continuous aggregate from * real-time to materialized-only or vice versa depending on the current state. @@ -3469,13 +3563,43 @@ build_union_query(CAggTimebucketInfo *tbinfo, int matpartcolno, Query *q1, Query * If there is join in CAgg definition then adjust varno * to get time column from the hypertable in the join. */ - if (list_length(q2->rtable) == CONTINUOUS_AGG_MAX_JOIN_RELATIONS) + + /* + * In case of joins it is enough to check if the first node is not RangeTblRef, + * because the jointree has RangeTblRef as leaves and JoinExpr above them. + * So if JoinExpr is present, it is the first node. + * Other cases of join i.e. without explicit JOIN clause is confirmed + * by reading the length of rtable. + */ + if (list_length(q2->rtable) == CONTINUOUS_AGG_MAX_JOIN_RELATIONS || + !IsA(linitial(q2->jointree->fromlist), RangeTblRef)) { 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); + RangeTblEntry *rte = NULL; + RangeTblEntry *rte_other = NULL; + + if (list_length(q2->rtable) == CONTINUOUS_AGG_MAX_JOIN_RELATIONS) + { + RangeTblRef *rtref = linitial_node(RangeTblRef, q2->jointree->fromlist); + rte = list_nth(q2->rtable, rtref->rtindex - 1); + RangeTblRef *rtref_other = lsecond_node(RangeTblRef, q2->jointree->fromlist); + rte_other = list_nth(q2->rtable, rtref_other->rtindex - 1); + } + else if (!IsA(linitial(q2->jointree->fromlist), RangeTblRef)) + { + ListCell *l; + foreach (l, q2->jointree->fromlist) + { + Node *jtnode = (Node *) lfirst(l); + JoinExpr *join = NULL; + if (IsA(jtnode, JoinExpr)) + { + join = castNode(JoinExpr, jtnode); + rte = list_nth(q2->rtable, ((RangeTblRef *) join->larg)->rtindex - 1); + rte_other = list_nth(q2->rtable, ((RangeTblRef *) join->rarg)->rtindex - 1); + } + } + } if (rte->relkind == RELKIND_VIEW) normal_table_id = rte_other->relid; else if (rte_other->relkind == RELKIND_VIEW) diff --git a/tsl/test/expected/cagg_joins-12.out b/tsl/test/expected/cagg_joins-12.out index ff9cfaa079c..4da2263c769 100644 --- a/tsl/test/expected/cagg_joins-12.out +++ b/tsl/test/expected/cagg_joins-12.out @@ -19,17 +19,17 @@ SELECT create_hypertable( INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-06-14', 'Moscow', 26,1), - ('2021-06-15', 'Moscow', 22,2), - ('2021-06-16', 'Moscow', 24,3), - ('2021-06-17', 'Moscow', 24,4), - ('2021-06-18', 'Moscow', 27,4), + ('2021-06-15', 'Berlin', 22,2), + ('2021-06-16', 'Stockholm', 24,3), + ('2021-06-17', 'London', 24,4), + ('2021-06-18', 'London', 27,4), ('2021-06-19', 'Moscow', 28,4), ('2021-06-20', 'Moscow', 30,1), - ('2021-06-21', 'Moscow', 31,1), - ('2021-06-22', 'Moscow', 34,1), - ('2021-06-23', 'Moscow', 34,2), + ('2021-06-21', 'Berlin', 31,1), + ('2021-06-22', 'Stockholm', 34,1), + ('2021-06-23', 'Stockholm', 34,2), ('2021-06-24', 'Moscow', 34,2), - ('2021-06-25', 'Moscow', 32,3), + ('2021-06-25', 'London', 32,3), ('2021-06-26', 'Moscow', 32,3), ('2021-06-27', 'Moscow', 31,3); CREATE TABLE conditions_dup AS SELECT * FROM conditions; @@ -93,6 +93,25 @@ UNION ALL WHERE conditions.device_id = devices.device_id AND conditions.day >= COALESCE(_timescaledb_internal.to_date(_timescaledb_internal.cagg_watermark(3)), '-infinity'::date) GROUP BY devices.name, (time_bucket('@ 1 day'::interval, conditions.day)); +SELECT * FROM conditions_summary_daily_realtime ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 +(14 rows) + INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-06-30', 'Moscow', 28, 3); SELECT * @@ -160,6 +179,26 @@ UNION ALL WHERE conditions.device_id = devices.device_id AND conditions.day >= COALESCE(_timescaledb_internal.to_date(_timescaledb_internal.cagg_watermark(4)), '-infinity'::date) GROUP BY devices.name, (time_bucket('@ 1 day'::interval, conditions.day)); +SELECT * FROM conditions_summary_daily_realtime_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(15 rows) + INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-07-01', 'Moscow', 28, 3); SELECT * @@ -200,6 +239,27 @@ WHERE conditions.device_id = devices.device_id 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. +SELECT * FROM conditions_summary_daily ORDER BY bucket; + bucket | avg | max | min | name | thermo_id +------------+---------------------+-----+-----+----------+----------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 | 1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 | 2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 | 3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 | 4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 | 4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 | 4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 | 1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 | 1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 | 1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 | 2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 | 2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 | 3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 | 3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 | 3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 | 3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 | 3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_reorder WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -212,6 +272,27 @@ WHERE conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_reorder" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_2 WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -223,6 +304,27 @@ FROM conditions JOIN devices ON conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_2" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_2 ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_2_reorder WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -233,6 +335,10 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket, FROM devices JOIN conditions ON conditions.device_id = devices.device_id GROUP BY name, bucket; ERROR: time bucket function must reference a hypertable dimension column +SELECT * FROM conditions_summary_daily_2_reorder ORDER BY bucket; +ERROR: relation "conditions_summary_daily_2_reorder" does not exist +LINE 1: SELECT * FROM conditions_summary_daily_2_reorder ORDER BY bu... + ^ CREATE MATERIALIZED VIEW conditions_summary_daily_3 WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -244,6 +350,10 @@ FROM devices JOIN conditions USING (device_id) GROUP BY name, bucket; ERROR: invalid continuous aggregate view DETAIL: Joins with USING clause in continuous aggregate definition work for Postgres versions 13 and above. +SELECT * FROM conditions_summary_daily_3 ORDER BY bucket; +ERROR: relation "conditions_summary_daily_3" does not exist +LINE 1: SELECT * FROM conditions_summary_daily_3 ORDER BY bucket; + ^ CREATE MATERIALIZED VIEW conditions_summary_daily_3_reorder WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -255,6 +365,83 @@ FROM conditions JOIN devices USING (device_id) GROUP BY name, bucket; ERROR: invalid continuous aggregate view DETAIL: Joins with USING clause in continuous aggregate definition work for Postgres versions 13 and above. +SELECT * FROM conditions_summary_daily_3_reorder ORDER BY bucket; +ERROR: relation "conditions_summary_daily_3_reorder" does not exist +LINE 1: SELECT * FROM conditions_summary_daily_3_reorder ORDER BY bu... + ^ +CREATE MATERIALIZED VIEW conditions_summary_daily_3_reorder_using_realtime +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices USING (device_id) +GROUP BY name, bucket; +ERROR: invalid continuous aggregate view +DETAIL: Joins with USING clause in continuous aggregate definition work for Postgres versions 13 and above. +SELECT * FROM conditions_summary_daily_3_reorder_using_realtime ORDER BY bucket; +ERROR: relation "conditions_summary_daily_3_reorder_using_realtime" does not exist +LINE 1: SELECT * FROM conditions_summary_daily_3_reorder_using_realt... + ^ +--Create CAgg with join and additional WHERE conditions +CREATE MATERIALIZED VIEW conditions_summary_daily_more_conds +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +WHERE conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_more_conds" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_more_conds ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 +(2 rows) + +--Create CAgg with join and ORDER BY +CREATE MATERIALIZED VIEW conditions_summary_daily_ordered +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +WHERE conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket +ORDER BY name; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_ordered" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_ordered ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 +(2 rows) + +--Error out when creating CAgg with multiple join conditions +CREATE MATERIALIZED VIEW conditions_summary_daily_more_joins_conds +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +AND conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket; +ERROR: invalid continuous aggregate view +DETAIL: Unsupported expression in join clause. +HINT: Only equality conditions are supported in continuous aggregates. --Error out for old format cagg definition CREATE MATERIALIZED VIEW conditions_summary_daily_cagg WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE, timescaledb.finalized = FALSE) AS @@ -458,7 +645,9 @@ 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 +NOTICE: drop cascades to 21 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 @@ -466,7 +655,7 @@ 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 18 other objects +NOTICE: drop cascades to 24 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 diff --git a/tsl/test/expected/cagg_joins-13.out b/tsl/test/expected/cagg_joins-13.out index d544be6be6f..4146c3d5b1b 100644 --- a/tsl/test/expected/cagg_joins-13.out +++ b/tsl/test/expected/cagg_joins-13.out @@ -19,17 +19,17 @@ SELECT create_hypertable( INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-06-14', 'Moscow', 26,1), - ('2021-06-15', 'Moscow', 22,2), - ('2021-06-16', 'Moscow', 24,3), - ('2021-06-17', 'Moscow', 24,4), - ('2021-06-18', 'Moscow', 27,4), + ('2021-06-15', 'Berlin', 22,2), + ('2021-06-16', 'Stockholm', 24,3), + ('2021-06-17', 'London', 24,4), + ('2021-06-18', 'London', 27,4), ('2021-06-19', 'Moscow', 28,4), ('2021-06-20', 'Moscow', 30,1), - ('2021-06-21', 'Moscow', 31,1), - ('2021-06-22', 'Moscow', 34,1), - ('2021-06-23', 'Moscow', 34,2), + ('2021-06-21', 'Berlin', 31,1), + ('2021-06-22', 'Stockholm', 34,1), + ('2021-06-23', 'Stockholm', 34,2), ('2021-06-24', 'Moscow', 34,2), - ('2021-06-25', 'Moscow', 32,3), + ('2021-06-25', 'London', 32,3), ('2021-06-26', 'Moscow', 32,3), ('2021-06-27', 'Moscow', 31,3); CREATE TABLE conditions_dup AS SELECT * FROM conditions; @@ -93,6 +93,25 @@ UNION ALL WHERE conditions.device_id = devices.device_id AND conditions.day >= COALESCE(_timescaledb_internal.to_date(_timescaledb_internal.cagg_watermark(3)), '-infinity'::date) GROUP BY devices.name, (time_bucket('@ 1 day'::interval, conditions.day)); +SELECT * FROM conditions_summary_daily_realtime ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 +(14 rows) + INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-06-30', 'Moscow', 28, 3); SELECT * @@ -160,6 +179,26 @@ UNION ALL WHERE conditions.device_id = devices.device_id AND conditions.day >= COALESCE(_timescaledb_internal.to_date(_timescaledb_internal.cagg_watermark(4)), '-infinity'::date) GROUP BY devices.name, (time_bucket('@ 1 day'::interval, conditions.day)); +SELECT * FROM conditions_summary_daily_realtime_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(15 rows) + INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-07-01', 'Moscow', 28, 3); SELECT * @@ -200,6 +239,27 @@ WHERE conditions.device_id = devices.device_id 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. +SELECT * FROM conditions_summary_daily ORDER BY bucket; + bucket | avg | max | min | name | thermo_id +------------+---------------------+-----+-----+----------+----------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 | 1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 | 2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 | 3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 | 4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 | 4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 | 4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 | 1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 | 1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 | 1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 | 2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 | 2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 | 3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 | 3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 | 3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 | 3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 | 3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_reorder WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -212,6 +272,27 @@ WHERE conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_reorder" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_2 WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -223,6 +304,27 @@ FROM conditions JOIN devices ON conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_2" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_2 ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_2_reorder WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -234,6 +336,27 @@ FROM devices JOIN conditions ON conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_2_reorder" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_2_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_3 WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -245,6 +368,27 @@ FROM devices JOIN conditions USING (device_id) GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_3" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_3 ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_3_reorder WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -256,6 +400,117 @@ FROM conditions JOIN devices USING (device_id) GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_3_reorder" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_3_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + +CREATE MATERIALIZED VIEW conditions_summary_daily_3_reorder_using_realtime +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices USING (device_id) +GROUP BY name, bucket; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_3_reorder_using_realtime" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_3_reorder_using_realtime ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + +--Create CAgg with join and additional WHERE conditions +CREATE MATERIALIZED VIEW conditions_summary_daily_more_conds +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +WHERE conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_more_conds" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_more_conds ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 +(2 rows) + +--Create CAgg with join and ORDER BY +CREATE MATERIALIZED VIEW conditions_summary_daily_ordered +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +WHERE conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket +ORDER BY name; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_ordered" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_ordered ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 +(2 rows) + +--Error out when creating CAgg with multiple join conditions +CREATE MATERIALIZED VIEW conditions_summary_daily_more_joins_conds +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +AND conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket; +ERROR: invalid continuous aggregate view +DETAIL: Unsupported expression in join clause. +HINT: Only equality conditions are supported in continuous aggregates. --Error out for old format cagg definition CREATE MATERIALIZED VIEW conditions_summary_daily_cagg WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE, timescaledb.finalized = FALSE) AS @@ -459,7 +714,10 @@ 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 +NOTICE: drop cascades to 33 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 @@ -470,7 +728,7 @@ 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 27 other objects +NOTICE: drop cascades to 36 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 diff --git a/tsl/test/expected/cagg_joins-14.out b/tsl/test/expected/cagg_joins-14.out index d544be6be6f..4146c3d5b1b 100644 --- a/tsl/test/expected/cagg_joins-14.out +++ b/tsl/test/expected/cagg_joins-14.out @@ -19,17 +19,17 @@ SELECT create_hypertable( INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-06-14', 'Moscow', 26,1), - ('2021-06-15', 'Moscow', 22,2), - ('2021-06-16', 'Moscow', 24,3), - ('2021-06-17', 'Moscow', 24,4), - ('2021-06-18', 'Moscow', 27,4), + ('2021-06-15', 'Berlin', 22,2), + ('2021-06-16', 'Stockholm', 24,3), + ('2021-06-17', 'London', 24,4), + ('2021-06-18', 'London', 27,4), ('2021-06-19', 'Moscow', 28,4), ('2021-06-20', 'Moscow', 30,1), - ('2021-06-21', 'Moscow', 31,1), - ('2021-06-22', 'Moscow', 34,1), - ('2021-06-23', 'Moscow', 34,2), + ('2021-06-21', 'Berlin', 31,1), + ('2021-06-22', 'Stockholm', 34,1), + ('2021-06-23', 'Stockholm', 34,2), ('2021-06-24', 'Moscow', 34,2), - ('2021-06-25', 'Moscow', 32,3), + ('2021-06-25', 'London', 32,3), ('2021-06-26', 'Moscow', 32,3), ('2021-06-27', 'Moscow', 31,3); CREATE TABLE conditions_dup AS SELECT * FROM conditions; @@ -93,6 +93,25 @@ UNION ALL WHERE conditions.device_id = devices.device_id AND conditions.day >= COALESCE(_timescaledb_internal.to_date(_timescaledb_internal.cagg_watermark(3)), '-infinity'::date) GROUP BY devices.name, (time_bucket('@ 1 day'::interval, conditions.day)); +SELECT * FROM conditions_summary_daily_realtime ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 +(14 rows) + INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-06-30', 'Moscow', 28, 3); SELECT * @@ -160,6 +179,26 @@ UNION ALL WHERE conditions.device_id = devices.device_id AND conditions.day >= COALESCE(_timescaledb_internal.to_date(_timescaledb_internal.cagg_watermark(4)), '-infinity'::date) GROUP BY devices.name, (time_bucket('@ 1 day'::interval, conditions.day)); +SELECT * FROM conditions_summary_daily_realtime_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(15 rows) + INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-07-01', 'Moscow', 28, 3); SELECT * @@ -200,6 +239,27 @@ WHERE conditions.device_id = devices.device_id 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. +SELECT * FROM conditions_summary_daily ORDER BY bucket; + bucket | avg | max | min | name | thermo_id +------------+---------------------+-----+-----+----------+----------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 | 1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 | 2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 | 3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 | 4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 | 4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 | 4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 | 1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 | 1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 | 1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 | 2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 | 2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 | 3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 | 3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 | 3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 | 3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 | 3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_reorder WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -212,6 +272,27 @@ WHERE conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_reorder" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_2 WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -223,6 +304,27 @@ FROM conditions JOIN devices ON conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_2" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_2 ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_2_reorder WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -234,6 +336,27 @@ FROM devices JOIN conditions ON conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_2_reorder" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_2_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_3 WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -245,6 +368,27 @@ FROM devices JOIN conditions USING (device_id) GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_3" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_3 ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_3_reorder WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -256,6 +400,117 @@ FROM conditions JOIN devices USING (device_id) GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_3_reorder" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_3_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + +CREATE MATERIALIZED VIEW conditions_summary_daily_3_reorder_using_realtime +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices USING (device_id) +GROUP BY name, bucket; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_3_reorder_using_realtime" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_3_reorder_using_realtime ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + +--Create CAgg with join and additional WHERE conditions +CREATE MATERIALIZED VIEW conditions_summary_daily_more_conds +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +WHERE conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_more_conds" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_more_conds ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 +(2 rows) + +--Create CAgg with join and ORDER BY +CREATE MATERIALIZED VIEW conditions_summary_daily_ordered +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +WHERE conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket +ORDER BY name; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_ordered" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_ordered ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 +(2 rows) + +--Error out when creating CAgg with multiple join conditions +CREATE MATERIALIZED VIEW conditions_summary_daily_more_joins_conds +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +AND conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket; +ERROR: invalid continuous aggregate view +DETAIL: Unsupported expression in join clause. +HINT: Only equality conditions are supported in continuous aggregates. --Error out for old format cagg definition CREATE MATERIALIZED VIEW conditions_summary_daily_cagg WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE, timescaledb.finalized = FALSE) AS @@ -459,7 +714,10 @@ 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 +NOTICE: drop cascades to 33 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 @@ -470,7 +728,7 @@ 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 27 other objects +NOTICE: drop cascades to 36 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 diff --git a/tsl/test/expected/cagg_joins-15.out b/tsl/test/expected/cagg_joins-15.out index d544be6be6f..4146c3d5b1b 100644 --- a/tsl/test/expected/cagg_joins-15.out +++ b/tsl/test/expected/cagg_joins-15.out @@ -19,17 +19,17 @@ SELECT create_hypertable( INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-06-14', 'Moscow', 26,1), - ('2021-06-15', 'Moscow', 22,2), - ('2021-06-16', 'Moscow', 24,3), - ('2021-06-17', 'Moscow', 24,4), - ('2021-06-18', 'Moscow', 27,4), + ('2021-06-15', 'Berlin', 22,2), + ('2021-06-16', 'Stockholm', 24,3), + ('2021-06-17', 'London', 24,4), + ('2021-06-18', 'London', 27,4), ('2021-06-19', 'Moscow', 28,4), ('2021-06-20', 'Moscow', 30,1), - ('2021-06-21', 'Moscow', 31,1), - ('2021-06-22', 'Moscow', 34,1), - ('2021-06-23', 'Moscow', 34,2), + ('2021-06-21', 'Berlin', 31,1), + ('2021-06-22', 'Stockholm', 34,1), + ('2021-06-23', 'Stockholm', 34,2), ('2021-06-24', 'Moscow', 34,2), - ('2021-06-25', 'Moscow', 32,3), + ('2021-06-25', 'London', 32,3), ('2021-06-26', 'Moscow', 32,3), ('2021-06-27', 'Moscow', 31,3); CREATE TABLE conditions_dup AS SELECT * FROM conditions; @@ -93,6 +93,25 @@ UNION ALL WHERE conditions.device_id = devices.device_id AND conditions.day >= COALESCE(_timescaledb_internal.to_date(_timescaledb_internal.cagg_watermark(3)), '-infinity'::date) GROUP BY devices.name, (time_bucket('@ 1 day'::interval, conditions.day)); +SELECT * FROM conditions_summary_daily_realtime ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 +(14 rows) + INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-06-30', 'Moscow', 28, 3); SELECT * @@ -160,6 +179,26 @@ UNION ALL WHERE conditions.device_id = devices.device_id AND conditions.day >= COALESCE(_timescaledb_internal.to_date(_timescaledb_internal.cagg_watermark(4)), '-infinity'::date) GROUP BY devices.name, (time_bucket('@ 1 day'::interval, conditions.day)); +SELECT * FROM conditions_summary_daily_realtime_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(15 rows) + INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-07-01', 'Moscow', 28, 3); SELECT * @@ -200,6 +239,27 @@ WHERE conditions.device_id = devices.device_id 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. +SELECT * FROM conditions_summary_daily ORDER BY bucket; + bucket | avg | max | min | name | thermo_id +------------+---------------------+-----+-----+----------+----------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 | 1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 | 2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 | 3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 | 4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 | 4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 | 4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 | 1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 | 1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 | 1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 | 2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 | 2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 | 3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 | 3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 | 3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 | 3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 | 3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_reorder WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -212,6 +272,27 @@ WHERE conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_reorder" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_2 WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -223,6 +304,27 @@ FROM conditions JOIN devices ON conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_2" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_2 ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_2_reorder WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -234,6 +336,27 @@ FROM devices JOIN conditions ON conditions.device_id = devices.device_id GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_2_reorder" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_2_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_3 WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -245,6 +368,27 @@ FROM devices JOIN conditions USING (device_id) GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_3" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_3 ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + CREATE MATERIALIZED VIEW conditions_summary_daily_3_reorder WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -256,6 +400,117 @@ FROM conditions JOIN devices USING (device_id) GROUP BY name, bucket; NOTICE: refreshing continuous aggregate "conditions_summary_daily_3_reorder" HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_3_reorder ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + +CREATE MATERIALIZED VIEW conditions_summary_daily_3_reorder_using_realtime +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices USING (device_id) +GROUP BY name, bucket; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_3_reorder_using_realtime" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_3_reorder_using_realtime ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-14-2021 | 26.0000000000000000 | 26 | 26 | thermo_1 + 06-15-2021 | 22.0000000000000000 | 22 | 22 | thermo_2 + 06-16-2021 | 24.0000000000000000 | 24 | 24 | thermo_3 + 06-17-2021 | 24.0000000000000000 | 24 | 24 | thermo_4 + 06-18-2021 | 27.0000000000000000 | 27 | 27 | thermo_4 + 06-19-2021 | 28.0000000000000000 | 28 | 28 | thermo_4 + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-21-2021 | 31.0000000000000000 | 31 | 31 | thermo_1 + 06-22-2021 | 34.0000000000000000 | 34 | 34 | thermo_1 + 06-23-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-24-2021 | 34.0000000000000000 | 34 | 34 | thermo_2 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-26-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 + 06-27-2021 | 31.0000000000000000 | 31 | 31 | thermo_3 + 06-30-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 + 07-01-2021 | 28.0000000000000000 | 28 | 28 | thermo_3 +(16 rows) + +--Create CAgg with join and additional WHERE conditions +CREATE MATERIALIZED VIEW conditions_summary_daily_more_conds +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +WHERE conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_more_conds" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_more_conds ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 +(2 rows) + +--Create CAgg with join and ORDER BY +CREATE MATERIALIZED VIEW conditions_summary_daily_ordered +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +WHERE conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket +ORDER BY name; +NOTICE: refreshing continuous aggregate "conditions_summary_daily_ordered" +HINT: Use WITH NO DATA if you do not want to refresh the continuous aggregate on creation. +SELECT * FROM conditions_summary_daily_ordered ORDER BY bucket; + bucket | avg | max | min | name +------------+---------------------+-----+-----+---------- + 06-20-2021 | 30.0000000000000000 | 30 | 30 | thermo_1 + 06-25-2021 | 32.0000000000000000 | 32 | 32 | thermo_3 +(2 rows) + +--Error out when creating CAgg with multiple join conditions +CREATE MATERIALIZED VIEW conditions_summary_daily_more_joins_conds +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +AND conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket; +ERROR: invalid continuous aggregate view +DETAIL: Unsupported expression in join clause. +HINT: Only equality conditions are supported in continuous aggregates. --Error out for old format cagg definition CREATE MATERIALIZED VIEW conditions_summary_daily_cagg WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE, timescaledb.finalized = FALSE) AS @@ -459,7 +714,10 @@ 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 +NOTICE: drop cascades to 33 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 @@ -470,7 +728,7 @@ 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 27 other objects +NOTICE: drop cascades to 36 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 diff --git a/tsl/test/sql/cagg_joins.sql.in b/tsl/test/sql/cagg_joins.sql.in index 0b5dd345676..55d87e936fb 100644 --- a/tsl/test/sql/cagg_joins.sql.in +++ b/tsl/test/sql/cagg_joins.sql.in @@ -16,17 +16,17 @@ SELECT create_hypertable( ); INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-06-14', 'Moscow', 26,1), - ('2021-06-15', 'Moscow', 22,2), - ('2021-06-16', 'Moscow', 24,3), - ('2021-06-17', 'Moscow', 24,4), - ('2021-06-18', 'Moscow', 27,4), + ('2021-06-15', 'Berlin', 22,2), + ('2021-06-16', 'Stockholm', 24,3), + ('2021-06-17', 'London', 24,4), + ('2021-06-18', 'London', 27,4), ('2021-06-19', 'Moscow', 28,4), ('2021-06-20', 'Moscow', 30,1), - ('2021-06-21', 'Moscow', 31,1), - ('2021-06-22', 'Moscow', 34,1), - ('2021-06-23', 'Moscow', 34,2), + ('2021-06-21', 'Berlin', 31,1), + ('2021-06-22', 'Stockholm', 34,1), + ('2021-06-23', 'Stockholm', 34,2), ('2021-06-24', 'Moscow', 34,2), - ('2021-06-25', 'Moscow', 32,3), + ('2021-06-25', 'London', 32,3), ('2021-06-26', 'Moscow', 32,3), ('2021-06-27', 'Moscow', 31,3); @@ -57,6 +57,7 @@ GROUP BY name, bucket; \d+ conditions_summary_daily_realtime +SELECT * FROM conditions_summary_daily_realtime ORDER BY bucket; INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-06-30', 'Moscow', 28, 3); @@ -81,6 +82,7 @@ GROUP BY name, bucket; \d+ conditions_summary_daily_realtime_reorder +SELECT * FROM conditions_summary_daily_realtime_reorder ORDER BY bucket; INSERT INTO conditions (day, city, temperature, device_id) VALUES ('2021-07-01', 'Moscow', 28, 3); @@ -102,6 +104,8 @@ FROM conditions, devices WHERE conditions.device_id = devices.device_id GROUP BY name, bucket, thermo_id; +SELECT * FROM conditions_summary_daily ORDER BY bucket; + CREATE MATERIALIZED VIEW conditions_summary_daily_reorder WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -113,6 +117,7 @@ FROM devices, conditions WHERE conditions.device_id = devices.device_id GROUP BY name, bucket; +SELECT * FROM conditions_summary_daily_reorder ORDER BY bucket; CREATE MATERIALIZED VIEW conditions_summary_daily_2 WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -123,6 +128,7 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket, FROM conditions JOIN devices ON conditions.device_id = devices.device_id GROUP BY name, bucket; +SELECT * FROM conditions_summary_daily_2 ORDER BY bucket; CREATE MATERIALIZED VIEW conditions_summary_daily_2_reorder WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -133,6 +139,7 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket, FROM devices JOIN conditions ON conditions.device_id = devices.device_id GROUP BY name, bucket; +SELECT * FROM conditions_summary_daily_2_reorder ORDER BY bucket; CREATE MATERIALIZED VIEW conditions_summary_daily_3 WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -143,6 +150,8 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket, FROM devices JOIN conditions USING (device_id) GROUP BY name, bucket; +SELECT * FROM conditions_summary_daily_3 ORDER BY bucket; + CREATE MATERIALIZED VIEW conditions_summary_daily_3_reorder WITH (timescaledb.continuous) AS SELECT time_bucket(INTERVAL '1 day', day) AS bucket, @@ -153,6 +162,64 @@ SELECT time_bucket(INTERVAL '1 day', day) AS bucket, FROM conditions JOIN devices USING (device_id) GROUP BY name, bucket; +SELECT * FROM conditions_summary_daily_3_reorder ORDER BY bucket; + +CREATE MATERIALIZED VIEW conditions_summary_daily_3_reorder_using_realtime +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices USING (device_id) +GROUP BY name, bucket; + +SELECT * FROM conditions_summary_daily_3_reorder_using_realtime ORDER BY bucket; + +--Create CAgg with join and additional WHERE conditions +CREATE MATERIALIZED VIEW conditions_summary_daily_more_conds +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +WHERE conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket; + +SELECT * FROM conditions_summary_daily_more_conds ORDER BY bucket; + +--Create CAgg with join and ORDER BY +CREATE MATERIALIZED VIEW conditions_summary_daily_ordered +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +WHERE conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket +ORDER BY name; + +SELECT * FROM conditions_summary_daily_ordered ORDER BY bucket; + +--Error out when creating CAgg with multiple join conditions +CREATE MATERIALIZED VIEW conditions_summary_daily_more_joins_conds +WITH (timescaledb.continuous, timescaledb.materialized_only = FALSE) AS +SELECT time_bucket(INTERVAL '1 day', day) AS bucket, + AVG(temperature), + MAX(temperature), + MIN(temperature), + name +FROM conditions JOIN devices ON conditions.device_id = devices.device_id +AND conditions.city = devices.location AND + conditions.temperature > 28 +GROUP BY name, bucket; + --Error out for old format cagg definition CREATE MATERIALIZED VIEW conditions_summary_daily_cagg WITH (timescaledb.continuous, timescaledb.materialized_only = TRUE, timescaledb.finalized = FALSE) AS