Skip to content

Commit

Permalink
Forbid users from altering the AS part of the ALTER TASK command.
Browse files Browse the repository at this point in the history
The SQL must always be a REFRESH command to maintain the integrity of
the Dynamic Table design (an auto-refreshing materialized view). Other
ALTER TASK subcommands remain allowed, enabling users to control other
aspects as needed.

Authored-by: Zhang Mingli [email protected]
  • Loading branch information
avamingli authored and my-ship-it committed Dec 18, 2024
1 parent d42a8c6 commit 57a5320
Show file tree
Hide file tree
Showing 3 changed files with 48 additions and 5 deletions.
9 changes: 8 additions & 1 deletion src/backend/commands/taskcmds.c
Original file line number Diff line number Diff line change
Expand Up @@ -251,7 +251,14 @@ AlterTask(ParseState *pstate, AlterTaskStmt * stmt)
}

if (d_sql != NULL && d_sql->arg)
sql = defGetString(d_sql);
{
if (strncmp(stmt->taskname, DYNAMIC_TASK_PREFIX, 25) == 0)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("can not alter REFRESH SQL of dynamic tables")));
else
sql = defGetString(d_sql);
}

AlterCronJob(jobid, schedule, sql, dbname, username, d_active != NULL ? &active : NULL);

Expand Down
29 changes: 27 additions & 2 deletions src/test/regress/expected/dynamic_table.out
Original file line number Diff line number Diff line change
Expand Up @@ -156,14 +156,14 @@ SELECT * FROM t1 WHERE a = 2;
(2 rows)

-- test DROP DYNAMIC TABLE
SELECT schedule, command FROM pg_task WHERE jobname LIKE 'gp_dynamic_table_refresh%' AND command LIKE '%dt0';
SELECT schedule, command FROM pg_task WHERE jobname LIKE 'gp_dynamic_table_refresh%' AND command LIKE '%dt0%';
schedule | command
-----------+------------------------------------------------
5 * * * * | REFRESH DYNAMIC TABLE dynamic_table_schema.dt0
(1 row)

DROP DYNAMIC TABLE dt0;
SELECT schedule, command FROM pg_task WHERE jobname LIKE 'gp_dynamic_table_refresh%' AND command LIKE '%dt0';
SELECT schedule, command FROM pg_task WHERE jobname LIKE 'gp_dynamic_table_refresh%' AND command LIKE '%dt0%';
schedule | command
----------+---------
(0 rows)
Expand Down Expand Up @@ -291,6 +291,11 @@ SELECT 'dt5'::regclass::oid AS dtoid \gset
CREATE TASK gp_dynamic_table_refresh_xxx SCHEDULE '1 second' AS 'REFRESH DYNAMIC TABLE dt5';
ERROR: unacceptable task name "gp_dynamic_table_refresh_xxx"
DETAIL: The prefix "gp_dynamic_table_refresh_" is reserved for system tasks.
-- can not alter the REFRESH SQL of Dynamic Tables.
ALTER TASK gp_dynamic_table_refresh_:dtoid AS '* * * * *';
ERROR: can not alter REFRESH SQL of dynamic tables
ALTER TASK gp_dynamic_table_refresh_:dtoid AS '';
ERROR: can not alter REFRESH SQL of dynamic tables
-- should fail
DROP TASK gp_dynamic_table_refresh_:dtoid;
ERROR: can not drop a internal task "gp_dynamic_table_refresh_17387" paried with dynamic table
Expand Down Expand Up @@ -338,6 +343,26 @@ SELECT * FROM pg_dynamic_tables;
| | | | | | FROM t2;
(4 rows)

CREATE TABLE t3(a int);
NOTICE: Table doesn't have 'DISTRIBUTED BY' clause -- Using column named 'a' as the Cloudberry Database data distribution key for this table.
HINT: The 'DISTRIBUTED BY' clause determines the distribution of data. Make sure column(s) chosen are the optimal data distribution key to minimize skew.
CREATE DYNAMIC TABLE dt_1_min SCHEDULE '* * * * *' AS SELECT * FROM t3 WITH NO DATA;
NOTICE: Table doesn't have 'DISTRIBUTED BY' clause -- Using column(s) named 'a' as the Cloudberry Database data distribution key for this table.
HINT: The 'DISTRIBUTED BY' clause determines the distribution of data. Make sure column(s) chosen are the optimal data distribution key to minimize skew.
INSERT INTO T3 VALUES(1);
-- wait for backgroud refresh
SELECT pg_sleep(80);
pg_sleep
----------

(1 row)

SELECT * FROM dt_1_min;
a
---
1
(1 row)

RESET enable_answer_query_using_materialized_views;
RESET optimizer;
--start_ignore
Expand Down
15 changes: 13 additions & 2 deletions src/test/regress/sql/dynamic_table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -54,9 +54,9 @@ SELECT * FROM t1 WHERE a = 2;
SELECT * FROM t1 WHERE a = 2;

-- test DROP DYNAMIC TABLE
SELECT schedule, command FROM pg_task WHERE jobname LIKE 'gp_dynamic_table_refresh%' AND command LIKE '%dt0';
SELECT schedule, command FROM pg_task WHERE jobname LIKE 'gp_dynamic_table_refresh%' AND command LIKE '%dt0%';
DROP DYNAMIC TABLE dt0;
SELECT schedule, command FROM pg_task WHERE jobname LIKE 'gp_dynamic_table_refresh%' AND command LIKE '%dt0';
SELECT schedule, command FROM pg_task WHERE jobname LIKE 'gp_dynamic_table_refresh%' AND command LIKE '%dt0%';

-- drop base tables will drop DYNAMIC TABLEs too.
SELECT schedule, command FROM pg_task WHERE jobname LIKE 'gp_dynamic_table_refresh%';
Expand Down Expand Up @@ -127,6 +127,10 @@ SELECT 'dt5'::regclass::oid AS dtoid \gset
-- should fail
CREATE TASK gp_dynamic_table_refresh_xxx SCHEDULE '1 second' AS 'REFRESH DYNAMIC TABLE dt5';

-- can not alter the REFRESH SQL of Dynamic Tables.
ALTER TASK gp_dynamic_table_refresh_:dtoid AS '* * * * *';
ALTER TASK gp_dynamic_table_refresh_:dtoid AS '';

-- should fail
DROP TASK gp_dynamic_table_refresh_:dtoid;

Expand All @@ -139,6 +143,13 @@ SELECT pg_catalog.pg_get_dynamic_table_schedule('t2'::regclass::oid);

SELECT * FROM pg_dynamic_tables;

CREATE TABLE t3(a int);
CREATE DYNAMIC TABLE dt_1_min SCHEDULE '* * * * *' AS SELECT * FROM t3 WITH NO DATA;
INSERT INTO T3 VALUES(1);
-- wait for backgroud refresh
SELECT pg_sleep(80);
SELECT * FROM dt_1_min;

RESET enable_answer_query_using_materialized_views;
RESET optimizer;
--start_ignore
Expand Down

0 comments on commit 57a5320

Please sign in to comment.