Skip to content

Commit

Permalink
[#23117] YSQL: Enable ALTER VIEW in parser
Browse files Browse the repository at this point in the history
Summary:
With this diff, the following ALTER VIEW commands are allowed:

  - ALTER VIEW [ IF EXISTS ] name ALTER [ COLUMN ] column_name SET DEFAULT expression
  - ALTER VIEW [ IF EXISTS ] name ALTER [ COLUMN ] column_name DROP DEFAULT
  - ALTER VIEW [ IF EXISTS ] name OWNER TO { new_owner | CURRENT_ROLE | CURRENT_USER | SESSION_USER }
  - ALTER VIEW [ IF EXISTS ] name RENAME TO new_name
  - ALTER VIEW [ IF EXISTS ] name SET SCHEMA new_schema

These commands do not require any additional YB changes, as they are metadata-only changes. Therefore, we only need to enable them in the parser.

Note: ALTER VIEW ... SET/RESET commands are not enabled as the generalized ALTER TABLE ... SET/RESET is not supported.
Jira: DB-12050

Test Plan: yb_view, yb_pg_create_view

Reviewers: myang, jason

Reviewed By: myang

Subscribers: jason, yql

Differential Revision: https://phorge.dev.yugabyte.com/D35937
  • Loading branch information
fizaaluthra committed Aug 8, 2024
1 parent 4768023 commit 3d4bc2a
Show file tree
Hide file tree
Showing 6 changed files with 312 additions and 44 deletions.
152 changes: 131 additions & 21 deletions src/postgres/contrib/postgres_fdw/expected/yb_pg_postgres_fdw.out
Original file line number Diff line number Diff line change
Expand Up @@ -2281,28 +2281,138 @@ GRANT SELECT ON ft4 TO regress_view_owner;
GRANT SELECT ON ft5 TO regress_view_owner;
CREATE VIEW v4 AS SELECT * FROM ft4;
CREATE VIEW v5 AS SELECT * FROM ft5;
-- YB note: ERROR: ALTER VIEW not supported yet, reenable commented out tests when issue #1131 is fixed
ALTER VIEW v5 OWNER TO regress_view_owner;
ERROR: ALTER VIEW not supported yet
LINE 1: ALTER VIEW v5 OWNER TO regress_view_owner;
^
HINT: See https://github.com/yugabyte/yugabyte-db/issues/1131. React with thumbs up to raise its priority
--EXPLAIN (VERBOSE, COSTS OFF)
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
--ALTER VIEW v4 OWNER TO regress_view_owner;
--EXPLAIN (VERBOSE, COSTS OFF)
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
--
--EXPLAIN (VERBOSE, COSTS OFF)
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
--ALTER VIEW v4 OWNER TO CURRENT_USER;
--EXPLAIN (VERBOSE, COSTS OFF)
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
--ALTER VIEW v4 OWNER TO regress_view_owner;
EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
QUERY PLAN
----------------------------------------------------------------------
Limit
Output: ft4.c1, ft5.c2, ft5.c1
-> Sort
Output: ft4.c1, ft5.c2, ft5.c1
Sort Key: ft4.c1, ft5.c1
-> Hash Left Join
Output: ft4.c1, ft5.c2, ft5.c1
Hash Cond: (ft4.c1 = ft5.c1)
-> Foreign Scan on public.ft4
Output: ft4.c1, ft4.c2, ft4.c3
Remote SQL: SELECT c1 FROM "S 1"."T 3"
-> Hash
Output: ft5.c2, ft5.c1
-> Foreign Scan on public.ft5
Output: ft5.c2, ft5.c1
Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
(16 rows)

SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
c1 | c2
----+----
22 |
24 | 25
26 |
28 |
30 | 31
32 |
34 |
36 | 37
38 |
40 |
(10 rows)

ALTER VIEW v4 OWNER TO regress_view_owner;
EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Limit
Output: ft4.c1, ft5.c2, ft5.c1
-> Foreign Scan
Output: ft4.c1, ft5.c2, ft5.c1
Relations: (public.ft4) LEFT JOIN (public.ft5)
Remote SQL: SELECT r6.c1, r9.c2, r9.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r9 ON (((r6.c1 = r9.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r9.c1 ASC NULLS LAST
(6 rows)

SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
c1 | c2
----+----
22 |
24 | 25
26 |
28 |
30 | 31
32 |
34 |
36 | 37
38 |
40 |
(10 rows)

EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
QUERY PLAN
----------------------------------------------------------------------
Limit
Output: ft4.c1, t2.c2, t2.c1
-> Sort
Output: ft4.c1, t2.c2, t2.c1
Sort Key: ft4.c1, t2.c1
-> Hash Left Join
Output: ft4.c1, t2.c2, t2.c1
Hash Cond: (ft4.c1 = t2.c1)
-> Foreign Scan on public.ft4
Output: ft4.c1, ft4.c2, ft4.c3
Remote SQL: SELECT c1 FROM "S 1"."T 3"
-> Hash
Output: t2.c2, t2.c1
-> Foreign Scan on public.ft5 t2
Output: t2.c2, t2.c1
Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
(16 rows)

SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
c1 | c2
----+----
22 |
24 | 25
26 |
28 |
30 | 31
32 |
34 |
36 | 37
38 |
40 |
(10 rows)

ALTER VIEW v4 OWNER TO CURRENT_USER;
EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Limit
Output: ft4.c1, t2.c2, t2.c1
-> Foreign Scan
Output: ft4.c1, t2.c2, t2.c1
Relations: (public.ft4) LEFT JOIN (public.ft5 t2)
Remote SQL: SELECT r6.c1, r2.c2, r2.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r2 ON (((r6.c1 = r2.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST
(6 rows)

SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
c1 | c2
----+----
22 |
24 | 25
26 |
28 |
30 | 31
32 |
34 |
36 | 37
38 |
40 |
(10 rows)

ALTER VIEW v4 OWNER TO regress_view_owner;
-- cleanup
DROP OWNED BY regress_view_owner;
DROP ROLE regress_view_owner;
Expand Down
33 changes: 16 additions & 17 deletions src/postgres/contrib/postgres_fdw/sql/yb_pg_postgres_fdw.sql
Original file line number Diff line number Diff line change
Expand Up @@ -600,24 +600,23 @@ GRANT SELECT ON ft5 TO regress_view_owner;

CREATE VIEW v4 AS SELECT * FROM ft4;
CREATE VIEW v5 AS SELECT * FROM ft5;
-- YB note: ERROR: ALTER VIEW not supported yet, reenable commented out tests when issue #1131 is fixed
ALTER VIEW v5 OWNER TO regress_view_owner;
--EXPLAIN (VERBOSE, COSTS OFF)
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
--ALTER VIEW v4 OWNER TO regress_view_owner;
--EXPLAIN (VERBOSE, COSTS OFF)
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
--
--EXPLAIN (VERBOSE, COSTS OFF)
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
--ALTER VIEW v4 OWNER TO CURRENT_USER;
--EXPLAIN (VERBOSE, COSTS OFF)
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
--SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
--ALTER VIEW v4 OWNER TO regress_view_owner;
EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
ALTER VIEW v4 OWNER TO regress_view_owner;
EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;

EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
ALTER VIEW v4 OWNER TO CURRENT_USER;
EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
ALTER VIEW v4 OWNER TO regress_view_owner;

-- cleanup
DROP OWNED BY regress_view_owner;
Expand Down
8 changes: 2 additions & 6 deletions src/postgres/src/backend/parser/gram.y
Original file line number Diff line number Diff line change
Expand Up @@ -2096,7 +2096,6 @@ AlterTableStmt:
}
| ALTER VIEW qualified_name alter_table_cmds
{
parser_ybc_signal_unsupported(@1, "ALTER VIEW", 1131);
AlterTableStmt *n = makeNode(AlterTableStmt);
n->relation = $3;
n->cmds = $4;
Expand All @@ -2106,7 +2105,6 @@ AlterTableStmt:
}
| ALTER VIEW IF_P EXISTS qualified_name alter_table_cmds
{
parser_ybc_signal_unsupported(@1, "ALTER VIEW", 1131);
AlterTableStmt *n = makeNode(AlterTableStmt);
n->relation = $5;
n->cmds = $6;
Expand Down Expand Up @@ -9572,7 +9570,6 @@ RenameStmt: ALTER AGGREGATE aggregate_with_argtypes RENAME TO name
}
| ALTER VIEW qualified_name RENAME TO name
{
parser_ybc_signal_unsupported(@1, "ALTER VIEW", 1131);
RenameStmt *n = makeNode(RenameStmt);
n->renameType = OBJECT_VIEW;
n->relation = $3;
Expand All @@ -9583,7 +9580,6 @@ RenameStmt: ALTER AGGREGATE aggregate_with_argtypes RENAME TO name
}
| ALTER VIEW IF_P EXISTS qualified_name RENAME TO name
{
parser_ybc_signal_unsupported(@1, "ALTER VIEW", 1131);
RenameStmt *n = makeNode(RenameStmt);
n->renameType = OBJECT_VIEW;
n->relation = $5;
Expand Down Expand Up @@ -10062,6 +10058,7 @@ AlterObjectSchemaStmt:
}
| ALTER TABLE relation_expr SET SCHEMA name
{
parser_ybc_not_support(@1, "ALTER TABLE SET SCHEMA");
AlterObjectSchemaStmt *n = makeNode(AlterObjectSchemaStmt);
n->objectType = OBJECT_TABLE;
n->relation = $3;
Expand All @@ -10071,6 +10068,7 @@ AlterObjectSchemaStmt:
}
| ALTER TABLE IF_P EXISTS relation_expr SET SCHEMA name
{
parser_ybc_not_support(@1, "ALTER TABLE SET SCHEMA");
AlterObjectSchemaStmt *n = makeNode(AlterObjectSchemaStmt);
n->objectType = OBJECT_TABLE;
n->relation = $5;
Expand Down Expand Up @@ -10146,7 +10144,6 @@ AlterObjectSchemaStmt:
}
| ALTER VIEW qualified_name SET SCHEMA name
{
parser_ybc_signal_unsupported(@1, "ALTER VIEW SET SCHEMA", 1131);
AlterObjectSchemaStmt *n = makeNode(AlterObjectSchemaStmt);
n->objectType = OBJECT_VIEW;
n->relation = $3;
Expand All @@ -10156,7 +10153,6 @@ AlterObjectSchemaStmt:
}
| ALTER VIEW IF_P EXISTS qualified_name SET SCHEMA name
{
parser_ybc_signal_unsupported(@1, "ALTER VIEW SET SCHEMA", 1131);
AlterObjectSchemaStmt *n = makeNode(AlterObjectSchemaStmt);
n->objectType = OBJECT_VIEW;
n->relation = $5;
Expand Down
123 changes: 123 additions & 0 deletions src/postgres/src/test/regress/expected/yb_view.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,123 @@
--
-- YB tests for views
--
CREATE TABLE test (a int, b int, c int DEFAULT 5);
INSERT INTO test VALUES (generate_series(1, 5), generate_series(1, 5));
CREATE VIEW test_view AS SELECT * FROM test ORDER BY a, b;
SELECT * FROM test_view;
a | b | c
---+---+---
1 | 1 | 5
2 | 2 | 5
3 | 3 | 5
4 | 4 | 5
5 | 5 | 5
(5 rows)

-- Tests for ALTER VIEW.
-- test ALTER VIEW ... ALTER COLUMN ... SET/DROP DEFAULT
ALTER VIEW test_view ALTER COLUMN c SET DEFAULT 10;
INSERT INTO test (a, b) VALUES (6, 6);
INSERT INTO test_view (a, b) VALUES (7, 7);
SELECT * FROM test_view;
a | b | c
---+---+----
1 | 1 | 5
2 | 2 | 5
3 | 3 | 5
4 | 4 | 5
5 | 5 | 5
6 | 6 | 5
7 | 7 | 10
(7 rows)

ALTER VIEW test_view ALTER COLUMN c DROP DEFAULT;
INSERT INTO test (a, b) VALUES (8, 8);
SELECT * FROM test_view;
a | b | c
---+---+----
1 | 1 | 5
2 | 2 | 5
3 | 3 | 5
4 | 4 | 5
5 | 5 | 5
6 | 6 | 5
7 | 7 | 10
8 | 8 | 5
(8 rows)

ALTER VIEW IF EXISTS non_existent_view ALTER COLUMN c SET DEFAULT 10;
NOTICE: relation "non_existent_view" does not exist, skipping
ALTER VIEW IF EXISTS non_existent_view ALTER COLUMN c DROP DEFAULT;
NOTICE: relation "non_existent_view" does not exist, skipping
-- test ALTER VIEW ... OWNER TO
CREATE ROLE test_role;
ALTER VIEW test_view OWNER TO test_role;
SELECT * FROM test_view;
ERROR: permission denied for table test
ALTER VIEW test_view OWNER TO CURRENT_USER;
SELECT * FROM test_view;
a | b | c
---+---+----
1 | 1 | 5
2 | 2 | 5
3 | 3 | 5
4 | 4 | 5
5 | 5 | 5
6 | 6 | 5
7 | 7 | 10
8 | 8 | 5
(8 rows)

ALTER VIEW IF EXISTS non_existent_view OWNER TO test_role;
NOTICE: relation "non_existent_view" does not exist, skipping
-- test ALTER VIEW ... RENAME
ALTER VIEW test_view RENAME TO test_view_renamed;
SELECT * FROM test_view_renamed;
a | b | c
---+---+----
1 | 1 | 5
2 | 2 | 5
3 | 3 | 5
4 | 4 | 5
5 | 5 | 5
6 | 6 | 5
7 | 7 | 10
8 | 8 | 5
(8 rows)

ALTER VIEW IF EXISTS non_existent_view RENAME TO non_existent_view_renamed;
NOTICE: relation "non_existent_view" does not exist, skipping
ALTER VIEW test_view_renamed RENAME TO test_view;
-- test ALTER VIEW ... SET SCHEMA
CREATE SCHEMA test_schema;
ALTER VIEW test_view SET SCHEMA test_schema;
SELECT * FROM test_schema.test_view;
a | b | c
---+---+----
1 | 1 | 5
2 | 2 | 5
3 | 3 | 5
4 | 4 | 5
5 | 5 | 5
6 | 6 | 5
7 | 7 | 10
8 | 8 | 5
(8 rows)

ALTER VIEW test_schema.test_view SET SCHEMA public;
SELECT * FROM test_view;
a | b | c
---+---+----
1 | 1 | 5
2 | 2 | 5
3 | 3 | 5
4 | 4 | 5
5 | 5 | 5
6 | 6 | 5
7 | 7 | 10
8 | 8 | 5
(8 rows)

ALTER VIEW IF EXISTS non_existent_view SET SCHEMA test_schema;
NOTICE: relation "non_existent_view" does not exist, skipping
Loading

0 comments on commit 3d4bc2a

Please sign in to comment.