summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/ref/alter_view.sgml
blob: 8bdc90a5a1c47d1468b68af6b396959572a4d5cf (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
<!--
doc/src/sgml/ref/alter_view.sgml
PostgreSQL documentation
-->

<refentry id="sql-alterview">
 <indexterm zone="sql-alterview">
  <primary>ALTER VIEW</primary>
 </indexterm>

 <refmeta>
  <refentrytitle>ALTER VIEW</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>ALTER VIEW</refname>
  <refpurpose>change the definition of a view</refpurpose>
 </refnamediv>

 <refsynopsisdiv>
<synopsis>
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_ROLE | 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>] [, ... ] )
ALTER VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable> RESET ( <replaceable class="parameter">view_option_name</replaceable> [, ... ] )
</synopsis>
 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

  <para>
   <command>ALTER VIEW</command> changes various auxiliary properties
   of a view.  (If you want to modify the view's defining query,
   use <command>CREATE OR REPLACE VIEW</command>.)
  </para>

  <para>
   You must own the view to use <command>ALTER VIEW</command>.
   To change a view's schema, you must also have <literal>CREATE</literal>
   privilege on the new schema.
   To alter the owner, you must also be a direct or indirect member of the new
   owning role, and that role must have <literal>CREATE</literal> privilege on
   the view's schema.  (These restrictions enforce that altering the owner
   doesn't do anything you couldn't do by dropping and recreating the view.
   However, a superuser can alter ownership of any view anyway.)
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <variablelist>
   <varlistentry>
    <term><replaceable class="parameter">name</replaceable></term>
    <listitem>
     <para>
      The name (optionally schema-qualified) of an existing view.
     </para>
    </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>
     <para>
      Do not throw an error if the view does not exist. A notice is issued
      in this case.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET</literal>/<literal>DROP DEFAULT</literal></term>
    <listitem>
     <para>
      These forms set or remove the default value for a column.
      A view column's default value is substituted into any
      <command>INSERT</command> or <command>UPDATE</command> command whose target is the
      view, before applying any rules or triggers for the view.  The view's
      default will therefore take precedence over any default values from
      underlying relations.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">new_owner</replaceable></term>
    <listitem>
     <para>
      The user name of the new owner of the view.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">new_name</replaceable></term>
    <listitem>
     <para>
      The new name for the view.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">new_schema</replaceable></term>
    <listitem>
     <para>
      The new schema for the view.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SET ( <replaceable class="parameter">view_option_name</replaceable> [= <replaceable class="parameter">view_option_value</replaceable>] [, ... ] )</literal></term>
    <term><literal>RESET ( <replaceable class="parameter">view_option_name</replaceable> [, ... ] )</literal></term>
    <listitem>
     <para>
      Sets or resets a view option.  Currently supported options are:
      <variablelist>
       <varlistentry>
        <term><literal>check_option</literal> (<type>enum</type>)</term>
        <listitem>
         <para>
          Changes the check option of the view.  The value must
          be <literal>local</literal> or <literal>cascaded</literal>.
         </para>
        </listitem>
       </varlistentry>
       <varlistentry>
        <term><literal>security_barrier</literal> (<type>boolean</type>)</term>
        <listitem>
         <para>
          Changes the security-barrier property of the view.  The value must
          be a Boolean value, such as <literal>true</literal>
          or <literal>false</literal>.
         </para>
        </listitem>
       </varlistentry>
       <varlistentry>
        <term><literal>security_invoker</literal> (<type>boolean</type>)</term>
        <listitem>
         <para>
          Changes the security-invoker property of the view.  The value must
          be a Boolean value, such as <literal>true</literal>
          or <literal>false</literal>.
         </para>
        </listitem>
       </varlistentry>
      </variablelist></para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1>
  <title>Notes</title>

  <para>
   For historical reasons, <command>ALTER TABLE</command> can be used with
   views too; but the only variants of <command>ALTER TABLE</command>
   that are allowed with views are equivalent to the ones shown above.
  </para>
 </refsect1>

 <refsect1>
  <title>Examples</title>

  <para>
   To rename the view <literal>foo</literal> to
   <literal>bar</literal>:
<programlisting>
ALTER VIEW foo RENAME TO bar;
</programlisting>
  </para>

  <para>
   To attach a default column value to an updatable view:
<programlisting>
CREATE TABLE base_table (id int, ts timestamptz);
CREATE VIEW a_view AS SELECT * FROM base_table;
ALTER VIEW a_view ALTER COLUMN ts SET DEFAULT now();
INSERT INTO base_table(id) VALUES(1);  -- ts will receive a NULL
INSERT INTO a_view(id) VALUES(2);  -- ts will receive the current time
</programlisting></para>
 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   <command>ALTER VIEW</command> is a <productname>PostgreSQL</productname>
   extension of the SQL standard.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-createview"/></member>
   <member><xref linkend="sql-dropview"/></member>
  </simplelist>
 </refsect1>
</refentry>