Skip to content

Commit

Permalink
Modify job_stats and continuous_aggregates view
Browse files Browse the repository at this point in the history
Use hypertable_schema and hypertable_name instead
of regclass hypertable in job_stats and
continuous_aggregates views.
  • Loading branch information
gayyappan committed Oct 1, 2020
1 parent 7f98d7f commit ef7f21d
Show file tree
Hide file tree
Showing 12 changed files with 55 additions and 45 deletions.
8 changes: 6 additions & 2 deletions sql/views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -43,7 +43,10 @@ CREATE OR REPLACE VIEW timescaledb_information.hypertables AS
AND ca.mat_hypertable_id IS NULL;

CREATE OR REPLACE VIEW timescaledb_information.job_stats as
SELECT format('%1$I.%2$I', ht.schema_name, ht.table_name)::regclass as hypertable, j.id AS job_id,
SELECT
ht.schema_name AS hypertable_schema,
ht.table_name AS hypertable_name,
j.id AS job_id,
js.last_start as last_run_started_at,
js.last_successful_finish as last_successful_finish,
CASE WHEN js.last_finish < '4714-11-24 00:00:00+00 BC' THEN NULL
Expand Down Expand Up @@ -90,7 +93,8 @@ CREATE OR REPLACE VIEW timescaledb_information.continuous_aggregates as
viewinfo.viewowner as view_owner,
bgwjob.schedule_interval,
cagg.materialized_only,
format('%1$I.%2$I', ht.schema_name, ht.table_name)::regclass as materialization_hypertable,
ht.schema_name as materialization_hypertable_schema,
ht.table_name as materialization_hypertable_name,
directview.viewdefinition as view_definition
FROM _timescaledb_catalog.continuous_agg cagg
LEFT JOIN _timescaledb_config.bgw_job bgwjob ON bgwjob.hypertable_id = cagg.mat_hypertable_id,
Expand Down
2 changes: 1 addition & 1 deletion test/sql/updates/post.continuous_aggs.v2.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ CALL refresh_continuous_aggregate('cagg.realtime_mat',NULL,NULL);

SELECT * FROM cagg.realtime_mat ORDER BY bucket, location;

SELECT view_name, schedule_interval, materialized_only, materialization_hypertable FROM timescaledb_information.continuous_aggregates ORDER BY view_name::text;
SELECT view_name, schedule_interval, materialized_only, materialization_hypertable_name FROM timescaledb_information.continuous_aggregates ORDER BY view_name::text;

SELECT maxtemp FROM mat_ignoreinval ORDER BY 1;

Expand Down
16 changes: 8 additions & 8 deletions tsl/test/expected/bgw_reorder_drop_chunks.out
Original file line number Diff line number Diff line change
Expand Up @@ -59,8 +59,8 @@ SELECT * FROM _timescaledb_config.bgw_job;
(0 rows)

SELECT * FROM timescaledb_information.job_stats;
hypertable | job_id | last_run_started_at | last_successful_finish | last_run_status | job_status | last_run_duration | next_scheduled_run | total_runs | total_successes | total_failures
------------+--------+---------------------+------------------------+-----------------+------------+-------------------+--------------------+------------+-----------------+----------------
hypertable_schema | hypertable_name | job_id | last_run_started_at | last_successful_finish | last_run_status | job_status | last_run_duration | next_scheduled_run | total_runs | total_successes | total_failures
-------------------+-----------------+--------+---------------------+------------------------+-----------------+------------+-------------------+--------------------+------------+-----------------+----------------
(0 rows)

\c :TEST_DBNAME :ROLE_DEFAULT_PERM_USER
Expand Down Expand Up @@ -292,9 +292,9 @@ SELECT indexrelid::regclass, indisclustered

--check that views work correctly
SELECT * FROM timescaledb_information.job_stats;
hypertable | job_id | last_run_started_at | last_successful_finish | last_run_status | job_status | last_run_duration | next_scheduled_run | total_runs | total_successes | total_failures
--------------------+--------+---------------------------------+---------------------------------+-----------------+------------+-------------------+---------------------------------+------------+-----------------+----------------
test_reorder_table | 1000 | Fri Dec 31 16:00:00.05 1999 PST | Fri Dec 31 16:00:00.05 1999 PST | Success | Scheduled | | Tue Jan 04 16:00:00.05 2000 PST | 3 | 3 | 0
hypertable_schema | hypertable_name | job_id | last_run_started_at | last_successful_finish | last_run_status | job_status | last_run_duration | next_scheduled_run | total_runs | total_successes | total_failures
-------------------+--------------------+--------+---------------------------------+---------------------------------+-----------------+------------+-------------------+---------------------------------+------------+-----------------+----------------
public | test_reorder_table | 1000 | Fri Dec 31 16:00:00.05 1999 PST | Fri Dec 31 16:00:00.05 1999 PST | Success | Scheduled | | Tue Jan 04 16:00:00.05 2000 PST | 3 | 3 | 0
(1 row)

-- test deleting the policy
Expand Down Expand Up @@ -569,8 +569,8 @@ SELECT show_chunks('test_drop_chunks_table');

--test that views work
SELECT * FROM timescaledb_information.job_stats;
hypertable | job_id | last_run_started_at | last_successful_finish | last_run_status | job_status | last_run_duration | next_scheduled_run | total_runs | total_successes | total_failures
------------------------+--------+------------------------------+------------------------------+-----------------+------------+-------------------+------------------------------+------------+-----------------+----------------
test_drop_chunks_table | 1001 | Fri Dec 31 16:00:01 1999 PST | Fri Dec 31 16:00:01 1999 PST | Success | Scheduled | | Fri Dec 31 16:00:02 1999 PST | 2 | 2 | 0
hypertable_schema | hypertable_name | job_id | last_run_started_at | last_successful_finish | last_run_status | job_status | last_run_duration | next_scheduled_run | total_runs | total_successes | total_failures
-------------------+------------------------+--------+------------------------------+------------------------------+-----------------+------------+-------------------+------------------------------+------------+-----------------+----------------
public | test_drop_chunks_table | 1001 | Fri Dec 31 16:00:01 1999 PST | Fri Dec 31 16:00:01 1999 PST | Success | Scheduled | | Fri Dec 31 16:00:02 1999 PST | 2 | 2 | 0
(1 row)

17 changes: 9 additions & 8 deletions tsl/test/expected/continuous_aggs_bgw.out
Original file line number Diff line number Diff line change
Expand Up @@ -58,8 +58,8 @@ SELECT * FROM _timescaledb_config.bgw_job;
(0 rows)

SELECT * FROM timescaledb_information.job_stats;
hypertable | job_id | last_run_started_at | last_successful_finish | last_run_status | job_status | last_run_duration | next_scheduled_run | total_runs | total_successes | total_failures
------------+--------+---------------------+------------------------+-----------------+------------+-------------------+--------------------+------------+-----------------+----------------
hypertable_schema | hypertable_name | job_id | last_run_started_at | last_successful_finish | last_run_status | job_status | last_run_duration | next_scheduled_run | total_runs | total_successes | total_failures
-------------------+-----------------+--------+---------------------+------------------------+-----------------+------------+-------------------+--------------------+------------+-----------------+----------------
(0 rows)

SELECT * FROM _timescaledb_catalog.continuous_agg;
Expand Down Expand Up @@ -448,13 +448,14 @@ SELECT * FROM test_continuous_agg_view ORDER BY 1;

\x on
--check the information views --
select view_name, view_owner, materialization_hypertable
select view_name, view_owner, materialization_hypertable_schema, materialization_hypertable_name
from timescaledb_information.continuous_aggregates
where view_name::text like '%test_continuous_agg_view';
-[ RECORD 1 ]--------------+-------------------------------------------------
view_name | test_continuous_agg_view
view_owner | default_perm_user
materialization_hypertable | _timescaledb_internal._materialized_hypertable_3
-[ RECORD 1 ]---------------------+---------------------------
view_name | test_continuous_agg_view
view_owner | default_perm_user
materialization_hypertable_schema | _timescaledb_internal
materialization_hypertable_name | _materialized_hypertable_3

select view_name, view_definition from timescaledb_information.continuous_aggregates
where view_name::text like '%test_continuous_agg_view';
Expand All @@ -468,7 +469,7 @@ view_definition | SELECT time_bucket(2, test_continuous_agg_table."time") AS ti
select job_status, last_run_duration
from timescaledb_information.job_stats ps, timescaledb_information.continuous_aggregates cagg
where cagg.view_name::text like '%test_continuous_agg_view'
and cagg.materialization_hypertable = ps.hypertable;
and cagg.materialization_hypertable_name = ps.hypertable_name;
-[ RECORD 1 ]-----+----------
job_status | Scheduled
last_run_duration |
Expand Down
10 changes: 5 additions & 5 deletions tsl/test/expected/continuous_aggs_multi.out
Original file line number Diff line number Diff line change
Expand Up @@ -38,12 +38,12 @@ AS
SELECT time_bucket(2, timeval), col1, max(col2)
FROM continuous_agg_test
GROUP BY 1, 2 WITH NO DATA;
select view_name, view_owner, materialization_hypertable
select view_name, view_owner, materialization_hypertable_name
from timescaledb_information.continuous_aggregates ORDER BY 1;
view_name | view_owner | materialization_hypertable
-----------+-------------------+--------------------------------------------------
cagg_1 | default_perm_user | _timescaledb_internal._materialized_hypertable_2
cagg_2 | default_perm_user | _timescaledb_internal._materialized_hypertable_3
view_name | view_owner | materialization_hypertable_name
-----------+-------------------+---------------------------------
cagg_1 | default_perm_user | _materialized_hypertable_2
cagg_2 | default_perm_user | _materialized_hypertable_3
(2 rows)

--TEST1: cagg_1 is materialized, not cagg_2.
Expand Down
4 changes: 3 additions & 1 deletion tsl/test/expected/continuous_aggs_permissions.out
Original file line number Diff line number Diff line change
Expand Up @@ -65,7 +65,9 @@ insert into conditions
select generate_series(0, 50, 10), 'NYC', 55, 75, 40, 70, NULL;
CALL refresh_continuous_aggregate(' mat_refresh_test', NULL, NULL);
SELECT id as cagg_job_id FROM _timescaledb_config.bgw_job order by id desc limit 1 \gset
SELECT materialization_hypertable FROM timescaledb_information.continuous_aggregates WHERE view_name = 'mat_refresh_test'::regclass \gset
SELECT format('%I.%I', materialization_hypertable_schema, materialization_hypertable_name ) as materialization_hypertable
FROM timescaledb_information.continuous_aggregates
WHERE view_name = 'mat_refresh_test'::regclass \gset
SELECT mat_hypertable_id FROM _timescaledb_catalog.continuous_agg WHERE user_view_name = 'mat_refresh_test' \gset
SELECT schema_name as mat_chunk_schema, table_name as mat_chunk_table
FROM _timescaledb_catalog.chunk
Expand Down
25 changes: 13 additions & 12 deletions tsl/test/expected/continuous_aggs_usage.out
Original file line number Diff line number Diff line change
Expand Up @@ -69,18 +69,19 @@ SELECT * FROM device_summary WHERE metric_spread = 1800 ORDER BY bucket DESC, de
--You can view informaton about your continuous aggregates. The meaning of these fields will be explained further down.
\x
SELECT * FROM timescaledb_information.continuous_aggregates;
-[ RECORD 1 ]--------------+-------------------------------------------------------------------------------------------------------------
view_name | device_summary
view_owner | default_perm_user
schedule_interval | @ 2 hours
materialized_only | t
materialization_hypertable | _timescaledb_internal._materialized_hypertable_2
view_definition | SELECT time_bucket('@ 1 hour'::interval, device_readings.observation_time) AS bucket, +
| device_readings.device_id, +
| avg(device_readings.metric) AS metric_avg, +
| (max(device_readings.metric) - min(device_readings.metric)) AS metric_spread +
| FROM device_readings +
| GROUP BY (time_bucket('@ 1 hour'::interval, device_readings.observation_time)), device_readings.device_id;
-[ RECORD 1 ]---------------------+-------------------------------------------------------------------------------------------------------------
view_name | device_summary
view_owner | default_perm_user
schedule_interval | @ 2 hours
materialized_only | t
materialization_hypertable_schema | _timescaledb_internal
materialization_hypertable_name | _materialized_hypertable_2
view_definition | SELECT time_bucket('@ 1 hour'::interval, device_readings.observation_time) AS bucket, +
| device_readings.device_id, +
| avg(device_readings.metric) AS metric_avg, +
| (max(device_readings.metric) - min(device_readings.metric)) AS metric_spread +
| FROM device_readings +
| GROUP BY (time_bucket('@ 1 hour'::interval, device_readings.observation_time)), device_readings.device_id;

\x
-- Refresh interval
Expand Down
6 changes: 3 additions & 3 deletions tsl/test/isolation/expected/continuous_aggs_multi.out
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ step Setup2:
BEGIN EXECUTE format( 'lock table %s', name);
END; $$ LANGUAGE plpgsql;

step LockMat1: BEGIN; select lock_mattable(materialization_hypertable::text) from timescaledb_information.continuous_aggregates where view_name::text like 'continuous_view_1';
step LockMat1: BEGIN; select lock_mattable(tab) FROM ( SELECT format('%I.%I',materialization_hypertable_schema, materialization_hypertable_name) as tab from timescaledb_information.continuous_aggregates where view_name::text like 'continuous_view_1') q ;

lock_mattable

Expand Down Expand Up @@ -44,7 +44,7 @@ step Setup2:

step Refresh1: CALL refresh_continuous_aggregate('continuous_view_1', NULL, 30);
step Refresh2: CALL refresh_continuous_aggregate('continuous_view_2', NULL, NULL);
step LockMat1: BEGIN; select lock_mattable(materialization_hypertable::text) from timescaledb_information.continuous_aggregates where view_name::text like 'continuous_view_1';
step LockMat1: BEGIN; select lock_mattable(tab) FROM ( SELECT format('%I.%I',materialization_hypertable_schema, materialization_hypertable_name) as tab from timescaledb_information.continuous_aggregates where view_name::text like 'continuous_view_1') q ;

lock_mattable

Expand Down Expand Up @@ -89,7 +89,7 @@ step Refresh2_sel: select * from continuous_view_2 where bkt = 0 or bkt > 30 ord
bkt maxl

0 4
step LockMat1: BEGIN; select lock_mattable(materialization_hypertable::text) from timescaledb_information.continuous_aggregates where view_name::text like 'continuous_view_1';
step LockMat1: BEGIN; select lock_mattable(tab) FROM ( SELECT format('%I.%I',materialization_hypertable_schema, materialization_hypertable_name) as tab from timescaledb_information.continuous_aggregates where view_name::text like 'continuous_view_1') q ;

lock_mattable

Expand Down
2 changes: 1 addition & 1 deletion tsl/test/isolation/specs/continuous_aggs_multi.spec
Original file line number Diff line number Diff line change
Expand Up @@ -59,7 +59,7 @@ step "Refresh2_sel" { select * from continuous_view_2 where bkt = 0 or bkt > 30

#locking the materialized table will block refresh1
session "LM1"
step "LockMat1" { BEGIN; select lock_mattable(materialization_hypertable::text) from timescaledb_information.continuous_aggregates where view_name::text like 'continuous_view_1';
step "LockMat1" { BEGIN; select lock_mattable(tab) FROM ( SELECT format('%I.%I',materialization_hypertable_schema, materialization_hypertable_name) as tab from timescaledb_information.continuous_aggregates where view_name::text like 'continuous_view_1') q ;
}
step "UnlockMat1" { ROLLBACK; }

Expand Down
4 changes: 2 additions & 2 deletions tsl/test/sql/continuous_aggs_bgw.sql
Original file line number Diff line number Diff line change
Expand Up @@ -264,7 +264,7 @@ SELECT * FROM test_continuous_agg_view ORDER BY 1;

\x on
--check the information views --
select view_name, view_owner, materialization_hypertable
select view_name, view_owner, materialization_hypertable_schema, materialization_hypertable_name
from timescaledb_information.continuous_aggregates
where view_name::text like '%test_continuous_agg_view';

Expand All @@ -274,7 +274,7 @@ where view_name::text like '%test_continuous_agg_view';
select job_status, last_run_duration
from timescaledb_information.job_stats ps, timescaledb_information.continuous_aggregates cagg
where cagg.view_name::text like '%test_continuous_agg_view'
and cagg.materialization_hypertable = ps.hypertable;
and cagg.materialization_hypertable_name = ps.hypertable_name;

\x off

Expand Down
2 changes: 1 addition & 1 deletion tsl/test/sql/continuous_aggs_multi.sql
Original file line number Diff line number Diff line change
Expand Up @@ -33,7 +33,7 @@ AS
FROM continuous_agg_test
GROUP BY 1, 2 WITH NO DATA;

select view_name, view_owner, materialization_hypertable
select view_name, view_owner, materialization_hypertable_name
from timescaledb_information.continuous_aggregates ORDER BY 1;

--TEST1: cagg_1 is materialized, not cagg_2.
Expand Down
4 changes: 3 additions & 1 deletion tsl/test/sql/continuous_aggs_permissions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -62,7 +62,9 @@ select generate_series(0, 50, 10), 'NYC', 55, 75, 40, 70, NULL;
CALL refresh_continuous_aggregate(' mat_refresh_test', NULL, NULL);

SELECT id as cagg_job_id FROM _timescaledb_config.bgw_job order by id desc limit 1 \gset
SELECT materialization_hypertable FROM timescaledb_information.continuous_aggregates WHERE view_name = 'mat_refresh_test'::regclass \gset
SELECT format('%I.%I', materialization_hypertable_schema, materialization_hypertable_name ) as materialization_hypertable
FROM timescaledb_information.continuous_aggregates
WHERE view_name = 'mat_refresh_test'::regclass \gset

SELECT mat_hypertable_id FROM _timescaledb_catalog.continuous_agg WHERE user_view_name = 'mat_refresh_test' \gset

Expand Down

0 comments on commit ef7f21d

Please sign in to comment.