Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add timescaledb_information.jobs view #2417

Merged
merged 1 commit into from
Sep 22, 2020
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
21 changes: 21 additions & 0 deletions sql/views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -69,6 +69,27 @@ CREATE OR REPLACE VIEW timescaledb_information.policy_stats as
INNER JOIN _timescaledb_internal.bgw_job_stat js on j.id = js.job_id
ORDER BY ht.schema_name, ht.table_name;

-- view for background worker jobs
CREATE OR REPLACE VIEW timescaledb_information.jobs AS
Copy link
Contributor

Choose a reason for hiding this comment

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

Should this be named policies instead? We now have 2 views related to jobs: one is called jobs and the other is called policy stats. Since the primary use case is for setting up policies, I suggest we rename this as timescaledb_information.policies.

Copy link
Member Author

Choose a reason for hiding this comment

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

the distinction i tried to introduce between job/policy is that job is something that is handled by the scheduler and it doesnt matter what it does, while policies are concrete implementations that have a specific purpose, so in that sense both should use job since the have nothing policy-specific in them

Copy link
Contributor

Choose a reason for hiding this comment

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

then policy_stats should be renamed to job_stats. Also better to get wider input on the name so that we don't have to back and revise it.

Copy link
Member Author

Choose a reason for hiding this comment

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

i would prefer job then it would also follow our catalog names, but keeping that job/policy distinction in mind i guess the new feature could also be called custom policies

SELECT j.id AS job_id,
j.application_name,
j.schedule_interval,
j.max_runtime,
j.max_retries,
j.retry_period,
j.proc_schema,
j.proc_name,
j.owner,
j.scheduled,
j.config,
Copy link
Contributor

Choose a reason for hiding this comment

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

I notice we're writing the entire jobs table except hypertable_id. While I agree that field isn't going to be publicly useful, it might be useful to join in the hypertable table and include the table name and schema.

Copy link
Member Author

Choose a reason for hiding this comment

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

hypertable_id is completely internal and may point to internal hypertables

Copy link
Contributor

Choose a reason for hiding this comment

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

Hmm, I do still think including the table name would be useful, though definitely less so when it points to an internal table. Right now if a user creates two policies with the same parameters, there is no way for them to tell from this new view which job is for which table.

Copy link
Member Author

Choose a reason for hiding this comment

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

in case of caggs this points to the materialization hypertable, i guess showing the name would be nice but what would you call the columns? for caggs we should resolve to the cagg view name which means we couldnt call the column hypertable_schema/name

Copy link
Contributor

Choose a reason for hiding this comment

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

I think it's actually okay to use the materialization hypertable for caggs as the continuous_aggregates information view also shows the materialization_hypertable, and can be used to match the job to the cagg view name.

Copy link
Member Author

Choose a reason for hiding this comment

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

ok added hypertable name and schema

js.next_start,
ht.schema_name AS hypertable_schema,
ht.table_name AS hypertable_name
FROM _timescaledb_config.bgw_job j
LEFT JOIN _timescaledb_catalog.hypertable ht ON ht.id = j.hypertable_id
LEFT JOIN _timescaledb_internal.bgw_job_stat js ON js.job_id = j.id
ORDER BY j.id;

-- views for continuous aggregate queries ---
CREATE OR REPLACE VIEW timescaledb_information.continuous_aggregates as
SELECT format('%1$I.%2$I', cagg.user_view_schema, cagg.user_view_name)::regclass as view_name,
Expand Down
3 changes: 2 additions & 1 deletion test/expected/pg_dump.out
Original file line number Diff line number Diff line change
Expand Up @@ -540,6 +540,7 @@ WHERE refclassid = 'pg_catalog.pg_extension'::pg_catalog.regclass AND
timescaledb_information.chunks
timescaledb_information.data_node
timescaledb_information.continuous_aggregates
timescaledb_information.jobs
timescaledb_information.policy_stats
timescaledb_information.license
timescaledb_information.hypertables
Expand All @@ -549,7 +550,7 @@ WHERE refclassid = 'pg_catalog.pg_extension'::pg_catalog.regclass AND
_timescaledb_internal.bgw_policy_chunk_stats
_timescaledb_internal.bgw_job_stat
_timescaledb_catalog.tablespace_id_seq
(14 rows)
(15 rows)

-- Make sure we can't run our restoring functions as a normal perm user as that would disable functionality for the whole db
\c :TEST_DBNAME :ROLE_DEFAULT_PERM_USER
Expand Down
52 changes: 32 additions & 20 deletions tsl/test/expected/bgw_custom.out
Original file line number Diff line number Diff line change
Expand Up @@ -56,6 +56,17 @@ SELECT add_job('custom_func_definer', '1h', config:='{"type":"function"}'::jsonb
1004
(1 row)

SELECT * FROM timescaledb_information.jobs ORDER BY 1;
job_id | application_name | schedule_interval | max_runtime | max_retries | retry_period | proc_schema | proc_name | owner | scheduled | config | next_start | hypertable_schema | hypertable_name
--------+------------------------+-------------------+-----------------+-------------+--------------+-----------------------+---------------------+-------------------+-----------+-----------------------+------------+-------------------+-----------------
1 | Telemetry Reporter [1] | @ 24 hours | @ 1 min 40 secs | -1 | @ 1 hour | _timescaledb_internal | policy_telemetry | super_user | t | | | |
1000 | Custom Job [1000] | @ 1 hour | @ 0 | -1 | @ 5 mins | public | custom_func | default_perm_user | t | {"type": "function"} | | |
1001 | Custom Job [1001] | @ 1 hour | @ 0 | -1 | @ 5 mins | public | custom_proc | default_perm_user | t | {"type": "procedure"} | | |
1002 | Custom Job [1002] | @ 1 hour | @ 0 | -1 | @ 5 mins | public | custom_proc2 | default_perm_user | t | {"type": "procedure"} | | |
1003 | Custom Job [1003] | @ 1 hour | @ 0 | -1 | @ 5 mins | public | custom_func | default_perm_user | t | {"type": "function"} | | |
1004 | Custom Job [1004] | @ 1 hour | @ 0 | -1 | @ 5 mins | public | custom_func_definer | default_perm_user | t | {"type": "function"} | | |
(6 rows)

CALL run_job(1000);
CALL run_job(1001);
CALL run_job(1002);
Expand Down Expand Up @@ -103,10 +114,11 @@ SELECT delete_job(1004);
(1 row)

-- check jobs got removed
SELECT * FROM _timescaledb_config.bgw_job WHERE id >= 1000;
id | application_name | schedule_interval | max_runtime | max_retries | retry_period | proc_schema | proc_name | owner | scheduled | hypertable_id | config
----+------------------+-------------------+-------------+-------------+--------------+-------------+-----------+-------+-----------+---------------+--------
(0 rows)
SELECT count(*) FROM timescaledb_information.jobs WHERE job_id >= 1000;
svenklemm marked this conversation as resolved.
Show resolved Hide resolved
count
-------
0
(1 row)

\c :TEST_DBNAME :ROLE_SUPERUSER
-- test altering job with NULL config
Expand All @@ -116,10 +128,10 @@ SELECT job_id FROM alter_job(1,scheduled:=false);
1
(1 row)

SELECT * FROM _timescaledb_config.bgw_job WHERE id = 1;
id | application_name | schedule_interval | max_runtime | max_retries | retry_period | proc_schema | proc_name | owner | scheduled | hypertable_id | config
----+------------------------+-------------------+-----------------+-------------+--------------+-----------------------+------------------+------------+-----------+---------------+--------
1 | Telemetry Reporter [1] | @ 24 hours | @ 1 min 40 secs | -1 | @ 1 hour | _timescaledb_internal | policy_telemetry | super_user | f | |
SELECT * FROM timescaledb_information.jobs WHERE job_id = 1;
job_id | application_name | schedule_interval | max_runtime | max_retries | retry_period | proc_schema | proc_name | owner | scheduled | config | next_start | hypertable_schema | hypertable_name
--------+------------------------+-------------------+-----------------+-------------+--------------+-----------------------+------------------+------------+-----------+--------+------------+-------------------+-----------------
1 | Telemetry Reporter [1] | @ 24 hours | @ 1 min 40 secs | -1 | @ 1 hour | _timescaledb_internal | policy_telemetry | super_user | f | | | |
(1 row)

-- test updating job settings
Expand All @@ -129,10 +141,10 @@ SELECT job_id FROM alter_job(1,config:='{"test":"test"}');
1
(1 row)

SELECT * FROM _timescaledb_config.bgw_job WHERE id = 1;
id | application_name | schedule_interval | max_runtime | max_retries | retry_period | proc_schema | proc_name | owner | scheduled | hypertable_id | config
----+------------------------+-------------------+-----------------+-------------+--------------+-----------------------+------------------+------------+-----------+---------------+------------------
1 | Telemetry Reporter [1] | @ 24 hours | @ 1 min 40 secs | -1 | @ 1 hour | _timescaledb_internal | policy_telemetry | super_user | f | | {"test": "test"}
SELECT * FROM timescaledb_information.jobs WHERE job_id = 1;
job_id | application_name | schedule_interval | max_runtime | max_retries | retry_period | proc_schema | proc_name | owner | scheduled | config | next_start | hypertable_schema | hypertable_name
--------+------------------------+-------------------+-----------------+-------------+--------------+-----------------------+------------------+------------+-----------+------------------+------------+-------------------+-----------------
1 | Telemetry Reporter [1] | @ 24 hours | @ 1 min 40 secs | -1 | @ 1 hour | _timescaledb_internal | policy_telemetry | super_user | f | {"test": "test"} | | |
(1 row)

SELECT job_id FROM alter_job(1,scheduled:=true);
Expand All @@ -141,10 +153,10 @@ SELECT job_id FROM alter_job(1,scheduled:=true);
1
(1 row)

SELECT * FROM _timescaledb_config.bgw_job WHERE id = 1;
id | application_name | schedule_interval | max_runtime | max_retries | retry_period | proc_schema | proc_name | owner | scheduled | hypertable_id | config
----+------------------------+-------------------+-----------------+-------------+--------------+-----------------------+------------------+------------+-----------+---------------+------------------
1 | Telemetry Reporter [1] | @ 24 hours | @ 1 min 40 secs | -1 | @ 1 hour | _timescaledb_internal | policy_telemetry | super_user | t | | {"test": "test"}
SELECT * FROM timescaledb_information.jobs WHERE job_id = 1;
job_id | application_name | schedule_interval | max_runtime | max_retries | retry_period | proc_schema | proc_name | owner | scheduled | config | next_start | hypertable_schema | hypertable_name
--------+------------------------+-------------------+-----------------+-------------+--------------+-----------------------+------------------+------------+-----------+------------------+------------+-------------------+-----------------
1 | Telemetry Reporter [1] | @ 24 hours | @ 1 min 40 secs | -1 | @ 1 hour | _timescaledb_internal | policy_telemetry | super_user | t | {"test": "test"} | | |
(1 row)

SELECT job_id FROM alter_job(1,scheduled:=false);
Expand All @@ -153,9 +165,9 @@ SELECT job_id FROM alter_job(1,scheduled:=false);
1
(1 row)

SELECT * FROM _timescaledb_config.bgw_job WHERE id = 1;
id | application_name | schedule_interval | max_runtime | max_retries | retry_period | proc_schema | proc_name | owner | scheduled | hypertable_id | config
----+------------------------+-------------------+-----------------+-------------+--------------+-----------------------+------------------+------------+-----------+---------------+------------------
1 | Telemetry Reporter [1] | @ 24 hours | @ 1 min 40 secs | -1 | @ 1 hour | _timescaledb_internal | policy_telemetry | super_user | f | | {"test": "test"}
SELECT * FROM timescaledb_information.jobs WHERE job_id = 1;
job_id | application_name | schedule_interval | max_runtime | max_retries | retry_period | proc_schema | proc_name | owner | scheduled | config | next_start | hypertable_schema | hypertable_name
--------+------------------------+-------------------+-----------------+-------------+--------------+-----------------------+------------------+------------+-----------+------------------+------------+-------------------+-----------------
1 | Telemetry Reporter [1] | @ 24 hours | @ 1 min 40 secs | -1 | @ 1 hour | _timescaledb_internal | policy_telemetry | super_user | f | {"test": "test"} | | |
(1 row)