From: Fujii Masao Date: Thu, 21 Nov 2019 10:55:13 +0000 (+0900) Subject: Allow ALTER VIEW command to rename the column in the view. X-Git-Tag: REL_13_BETA1~1141 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=30840c92ac0c4073fb7bc8222317630571b8cf25;p=thirdparty%2Fpostgresql.git Allow ALTER VIEW command to rename the column in the view. ALTER TABLE RENAME COLUMN command always can be used to rename the column in the view, but it's reasonable to add that syntax to ALTER VIEW too. Author: Fujii Masao Reviewed-by: Ibrar Ahmed, Yu Kimura Discussion: https://postgr.es/m/CAHGQGwHoQMD3b-MqTLcp1MgdhCpOKU7QNRwjFooT4_d+ti5v6g@mail.gmail.com --- diff --git a/doc/src/sgml/ref/alter_view.sgml b/doc/src/sgml/ref/alter_view.sgml index 2e9edc19758..b66160bfb89 100644 --- a/doc/src/sgml/ref/alter_view.sgml +++ b/doc/src/sgml/ref/alter_view.sgml @@ -24,6 +24,7 @@ PostgreSQL documentation 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_USER | SESSION_USER } +ALTER VIEW [ IF EXISTS ] name RENAME [ COLUMN ] column_name TO new_column_name ALTER VIEW [ IF EXISTS ] name RENAME TO new_name ALTER VIEW [ IF EXISTS ] name SET SCHEMA new_schema ALTER VIEW [ IF EXISTS ] name SET ( view_option_name [= view_option_value] [, ... ] ) @@ -65,6 +66,24 @@ ALTER VIEW [ IF EXISTS ] name RESET + + column_name + + + Name of an existing column. + + + + + + new_column_name + + + New name for an existing column. + + + + IF EXISTS diff --git a/src/backend/commands/view.c b/src/backend/commands/view.c index 9fa433a9754..9b5148093b6 100644 --- a/src/backend/commands/view.c +++ b/src/backend/commands/view.c @@ -276,7 +276,8 @@ checkViewTupleDesc(TupleDesc newdesc, TupleDesc olddesc) (errcode(ERRCODE_INVALID_TABLE_DEFINITION), errmsg("cannot change name of view column \"%s\" to \"%s\"", NameStr(oldattr->attname), - NameStr(newattr->attname)))); + NameStr(newattr->attname)), + errhint("Use ALTER VIEW ... RENAME COLUMN ... to change name of view column instead."))); /* XXX would it be safe to allow atttypmod to change? Not sure */ if (newattr->atttypid != oldattr->atttypid || newattr->atttypmod != oldattr->atttypmod) diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 2f7bd662e8a..c5086846dec 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -8777,6 +8777,28 @@ RenameStmt: ALTER AGGREGATE aggregate_with_argtypes RENAME TO name n->missing_ok = true; $$ = (Node *)n; } + | ALTER VIEW qualified_name RENAME opt_column name TO name + { + RenameStmt *n = makeNode(RenameStmt); + n->renameType = OBJECT_COLUMN; + n->relationType = OBJECT_VIEW; + n->relation = $3; + n->subname = $6; + n->newname = $8; + n->missing_ok = false; + $$ = (Node *)n; + } + | ALTER VIEW IF_P EXISTS qualified_name RENAME opt_column name TO name + { + RenameStmt *n = makeNode(RenameStmt); + n->renameType = OBJECT_COLUMN; + n->relationType = OBJECT_VIEW; + n->relation = $5; + n->subname = $8; + n->newname = $10; + n->missing_ok = true; + $$ = (Node *)n; + } | ALTER MATERIALIZED VIEW qualified_name RENAME opt_column name TO name { RenameStmt *n = makeNode(RenameStmt); diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c index 1578568a91c..172e00b46ef 100644 --- a/src/bin/psql/tab-complete.c +++ b/src/bin/psql/tab-complete.c @@ -1797,8 +1797,20 @@ psql_completion(const char *text, int start, int end) COMPLETE_WITH("TO"); /* ALTER VIEW */ else if (Matches("ALTER", "VIEW", MatchAny)) - COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME TO", + COMPLETE_WITH("ALTER COLUMN", "OWNER TO", "RENAME", "SET SCHEMA"); + /* ALTER VIEW xxx RENAME */ + else if (Matches("ALTER", "VIEW", MatchAny, "RENAME")) + COMPLETE_WITH_ATTR(prev2_wd, " UNION SELECT 'COLUMN' UNION SELECT 'TO'"); + else if (Matches("ALTER", "VIEW", MatchAny, "ALTER|RENAME", "COLUMN")) + COMPLETE_WITH_ATTR(prev3_wd, ""); + /* ALTER VIEW xxx RENAME yyy */ + else if (Matches("ALTER", "VIEW", MatchAny, "RENAME", MatchAnyExcept("TO"))) + COMPLETE_WITH("TO"); + /* ALTER VIEW xxx RENAME COLUMN yyy */ + else if (Matches("ALTER", "VIEW", MatchAny, "RENAME", "COLUMN", MatchAnyExcept("TO"))) + COMPLETE_WITH("TO"); + /* ALTER MATERIALIZED VIEW */ else if (Matches("ALTER", "MATERIALIZED", "VIEW", MatchAny)) COMPLETE_WITH("ALTER COLUMN", "CLUSTER ON", "DEPENDS ON EXTENSION", diff --git a/src/test/regress/expected/create_view.out b/src/test/regress/expected/create_view.out index 2fd36ca9a14..9a92629fd79 100644 --- a/src/test/regress/expected/create_view.out +++ b/src/test/regress/expected/create_view.out @@ -64,6 +64,7 @@ ERROR: cannot drop columns from view CREATE OR REPLACE VIEW viewtest AS SELECT 1, * FROM viewtest_tbl; ERROR: cannot change name of view column "a" to "?column?" +HINT: Use ALTER VIEW ... RENAME COLUMN ... to change name of view column instead. -- should fail CREATE OR REPLACE VIEW viewtest AS SELECT a, b::numeric FROM viewtest_tbl; @@ -1189,6 +1190,29 @@ select pg_get_viewdef('vv1', true); CROSS JOIN tt6) j(aa, bb, cc_1, cc, dd); (1 row) +create view v4 as select * from v1; +alter view v1 rename column a to x; +select pg_get_viewdef('v1', true); + pg_get_viewdef +--------------------------------------------------- + SELECT tt2.b, + + tt3.c, + + tt2.a AS x, + + tt3.ax + + FROM tt2 + + JOIN tt3 tt3(ax, b, c, c_1, e) USING (b, c); +(1 row) + +select pg_get_viewdef('v4', true); + pg_get_viewdef +---------------- + SELECT v1.b, + + v1.c, + + v1.x AS a,+ + v1.ax + + FROM v1; +(1 row) + -- Unnamed FULL JOIN USING is lots of fun too create table tt7 (x int, xx int, y int); alter table tt7 drop column xx; @@ -1782,7 +1806,7 @@ drop cascades to view aliased_view_2 drop cascades to view aliased_view_3 drop cascades to view aliased_view_4 DROP SCHEMA testviewschm2 CASCADE; -NOTICE: drop cascades to 63 other objects +NOTICE: drop cascades to 64 other objects DETAIL: drop cascades to table t1 drop cascades to view temporal1 drop cascades to view temporal2 @@ -1818,6 +1842,7 @@ drop cascades to view v3 drop cascades to table tt5 drop cascades to table tt6 drop cascades to view vv1 +drop cascades to view v4 drop cascades to table tt7 drop cascades to table tt8 drop cascades to view vv2 diff --git a/src/test/regress/sql/create_view.sql b/src/test/regress/sql/create_view.sql index 8c0f45cc526..be5d90727a9 100644 --- a/src/test/regress/sql/create_view.sql +++ b/src/test/regress/sql/create_view.sql @@ -391,6 +391,12 @@ select pg_get_viewdef('vv1', true); alter table tt5 drop column c; select pg_get_viewdef('vv1', true); +create view v4 as select * from v1; +alter view v1 rename column a to x; +select pg_get_viewdef('v1', true); +select pg_get_viewdef('v4', true); + + -- Unnamed FULL JOIN USING is lots of fun too create table tt7 (x int, xx int, y int);