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
This commit is contained in:
Fujii Masao 2019-11-21 19:55:13 +09:00
parent 61a956d9cc
commit 30840c92ac
6 changed files with 88 additions and 3 deletions

View File

@ -24,6 +24,7 @@ PostgreSQL documentation
ALTER VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> SET DEFAULT <replaceable class="parameter">expression</replaceable>
ALTER VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable> ALTER [ COLUMN ] <replaceable class="parameter">column_name</replaceable> DROP DEFAULT
ALTER VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable> OWNER TO { <replaceable class="parameter">new_owner</replaceable> | CURRENT_USER | SESSION_USER }
ALTER VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable> RENAME [ COLUMN ] <replaceable class="parameter">column_name</replaceable> TO <replaceable class="parameter">new_column_name</replaceable>
ALTER VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable> RENAME TO <replaceable class="parameter">new_name</replaceable>
ALTER VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable> SET SCHEMA <replaceable class="parameter">new_schema</replaceable>
ALTER VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable> SET ( <replaceable class="parameter">view_option_name</replaceable> [= <replaceable class="parameter">view_option_value</replaceable>] [, ... ] )
@ -65,6 +66,24 @@ ALTER VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable> RESET
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">column_name</replaceable></term>
<listitem>
<para>
Name of an existing column.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">new_column_name</replaceable></term>
<listitem>
<para>
New name for an existing column.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>IF EXISTS</literal></term>
<listitem>

View File

@ -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)

View File

@ -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);

View File

@ -1797,8 +1797,20 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("TO");
/* ALTER VIEW <name> */
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 <name> */
else if (Matches("ALTER", "MATERIALIZED", "VIEW", MatchAny))
COMPLETE_WITH("ALTER COLUMN", "CLUSTER ON", "DEPENDS ON EXTENSION",

View File

@ -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

View File

@ -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);