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
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
|
<!--
doc/src/sgml/ref/alter_function.sgml
PostgreSQL documentation
-->
<refentry id="sql-alterfunction">
<indexterm zone="sql-alterfunction">
<primary>ALTER FUNCTION</primary>
</indexterm>
<refmeta>
<refentrytitle>ALTER FUNCTION</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>ALTER FUNCTION</refname>
<refpurpose>change the definition of a function</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
ALTER FUNCTION <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
<replaceable class="parameter">action</replaceable> [ ... ] [ RESTRICT ]
ALTER FUNCTION <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
RENAME TO <replaceable>new_name</replaceable>
ALTER FUNCTION <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
OWNER TO { <replaceable>new_owner</replaceable> | CURRENT_ROLE | CURRENT_USER | SESSION_USER }
ALTER FUNCTION <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
SET SCHEMA <replaceable>new_schema</replaceable>
ALTER FUNCTION <replaceable>name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) ]
[ NO ] DEPENDS ON EXTENSION <replaceable>extension_name</replaceable>
<phrase>where <replaceable class="parameter">action</replaceable> is one of:</phrase>
CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
IMMUTABLE | STABLE | VOLATILE
[ NOT ] LEAKPROOF
[ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
PARALLEL { UNSAFE | RESTRICTED | SAFE }
COST <replaceable class="parameter">execution_cost</replaceable>
ROWS <replaceable class="parameter">result_rows</replaceable>
SUPPORT <replaceable class="parameter">support_function</replaceable>
SET <replaceable class="parameter">configuration_parameter</replaceable> { TO | = } { <replaceable class="parameter">value</replaceable> | DEFAULT }
SET <replaceable class="parameter">configuration_parameter</replaceable> FROM CURRENT
RESET <replaceable class="parameter">configuration_parameter</replaceable>
RESET ALL
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>ALTER FUNCTION</command> changes the definition of a
function.
</para>
<para>
You must own the function to use <command>ALTER FUNCTION</command>.
To change a function's schema, you must also have <literal>CREATE</literal>
privilege on the new schema. To alter the owner, you must be able to
<literal>SET ROLE</literal> to the new owning role, and that role must
have <literal>CREATE</literal> privilege on
the function's schema. (These restrictions enforce that altering the owner
doesn't do anything you couldn't do by dropping and recreating the function.
However, a superuser can alter ownership of any function 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 function. If no
argument list is specified, the name must be unique in its schema.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">argmode</replaceable></term>
<listitem>
<para>
The mode of an argument: <literal>IN</literal>, <literal>OUT</literal>,
<literal>INOUT</literal>, or <literal>VARIADIC</literal>.
If omitted, the default is <literal>IN</literal>.
Note that <command>ALTER FUNCTION</command> does not actually pay
any attention to <literal>OUT</literal> arguments, since only the input
arguments are needed to determine the function's identity.
So it is sufficient to list the <literal>IN</literal>, <literal>INOUT</literal>,
and <literal>VARIADIC</literal> arguments.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">argname</replaceable></term>
<listitem>
<para>
The name of an argument.
Note that <command>ALTER FUNCTION</command> does not actually pay
any attention to argument names, since only the argument data
types are needed to determine the function's identity.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">argtype</replaceable></term>
<listitem>
<para>
The data type(s) of the function's arguments (optionally
schema-qualified), if any.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">new_name</replaceable></term>
<listitem>
<para>
The new name of the function.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">new_owner</replaceable></term>
<listitem>
<para>
The new owner of the function. Note that if the function is
marked <literal>SECURITY DEFINER</literal>, it will subsequently
execute as the new owner.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">new_schema</replaceable></term>
<listitem>
<para>
The new schema for the function.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>DEPENDS ON EXTENSION <replaceable class="parameter">extension_name</replaceable></literal></term>
<term><literal>NO DEPENDS ON EXTENSION <replaceable class="parameter">extension_name</replaceable></literal></term>
<listitem>
<para>
This form marks the function as dependent on the extension, or no longer
dependent on that extension if <literal>NO</literal> is specified.
A function that's marked as dependent on an extension is dropped when the
extension is dropped, even if <literal>CASCADE</literal> is not specified.
A function can depend upon multiple extensions, and will be dropped when
any one of those extensions is dropped.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CALLED ON NULL INPUT</literal></term>
<term><literal>RETURNS NULL ON NULL INPUT</literal></term>
<term><literal>STRICT</literal></term>
<listitem>
<para><literal>CALLED ON NULL INPUT</literal> changes the function so
that it will be invoked when some or all of its arguments are
null. <literal>RETURNS NULL ON NULL INPUT</literal> or
<literal>STRICT</literal> changes the function so that it is not
invoked if any of its arguments are null; instead, a null result
is assumed automatically. See <xref linkend="sql-createfunction"/>
for more information.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>IMMUTABLE</literal></term>
<term><literal>STABLE</literal></term>
<term><literal>VOLATILE</literal></term>
<listitem>
<para>
Change the volatility of the function to the specified setting.
See <xref linkend="sql-createfunction"/> for details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal><optional> EXTERNAL </optional> SECURITY INVOKER</literal></term>
<term><literal><optional> EXTERNAL </optional> SECURITY DEFINER</literal></term>
<listitem>
<para>
Change whether the function is a security definer or not. The
key word <literal>EXTERNAL</literal> is ignored for SQL
conformance. See <xref linkend="sql-createfunction"/> for more information about
this capability.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>PARALLEL</literal></term>
<listitem>
<para>
Change whether the function is deemed safe for parallelism.
See <xref linkend="sql-createfunction"/> for details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>LEAKPROOF</literal></term>
<listitem>
<para>
Change whether the function is considered leakproof or not.
See <xref linkend="sql-createfunction"/> for more information about
this capability.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>COST</literal> <replaceable class="parameter">execution_cost</replaceable></term>
<listitem>
<para>
Change the estimated execution cost of the function.
See <xref linkend="sql-createfunction"/> for more information.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>ROWS</literal> <replaceable class="parameter">result_rows</replaceable></term>
<listitem>
<para>
Change the estimated number of rows returned by a set-returning
function. See <xref linkend="sql-createfunction"/> for more information.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SUPPORT</literal> <replaceable class="parameter">support_function</replaceable></term>
<listitem>
<para>
Set or change the planner support function to use for this function.
See <xref linkend="xfunc-optimization"/> for details. You must be
superuser to use this option.
</para>
<para>
This option cannot be used to remove the support function altogether,
since it must name a new support function. Use <command>CREATE OR
REPLACE FUNCTION</command> if you need to do that.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>configuration_parameter</replaceable></term>
<term><replaceable>value</replaceable></term>
<listitem>
<para>
Add or change the assignment to be made to a configuration parameter
when the function is called. If
<replaceable>value</replaceable> is <literal>DEFAULT</literal>
or, equivalently, <literal>RESET</literal> is used, the function-local
setting is removed, so that the function executes with the value
present in its environment. Use <literal>RESET
ALL</literal> to clear all function-local settings.
<literal>SET FROM CURRENT</literal> saves the value of the parameter that
is current when <command>ALTER FUNCTION</command> is executed as the value
to be applied when the function is entered.
</para>
<para>
See <xref linkend="sql-set"/> and
<xref linkend="runtime-config"/>
for more information about allowed parameter names and values.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>RESTRICT</literal></term>
<listitem>
<para>
Ignored for conformance with the SQL standard.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
To rename the function <literal>sqrt</literal> for type
<type>integer</type> to <literal>square_root</literal>:
<programlisting>
ALTER FUNCTION sqrt(integer) RENAME TO square_root;
</programlisting>
</para>
<para>
To change the owner of the function <literal>sqrt</literal> for type
<type>integer</type> to <literal>joe</literal>:
<programlisting>
ALTER FUNCTION sqrt(integer) OWNER TO joe;
</programlisting>
</para>
<para>
To change the schema of the function <literal>sqrt</literal> for type
<type>integer</type> to <literal>maths</literal>:
<programlisting>
ALTER FUNCTION sqrt(integer) SET SCHEMA maths;
</programlisting>
</para>
<para>
To mark the function <literal>sqrt</literal> for type
<type>integer</type> as being dependent on the extension
<literal>mathlib</literal>:
<programlisting>
ALTER FUNCTION sqrt(integer) DEPENDS ON EXTENSION mathlib;
</programlisting>
</para>
<para>
To adjust the search path that is automatically set for a function:
<programlisting>
ALTER FUNCTION check_password(text) SET search_path = admin, pg_temp;
</programlisting>
</para>
<para>
To disable automatic setting of <varname>search_path</varname> for a function:
<programlisting>
ALTER FUNCTION check_password(text) RESET search_path;
</programlisting>
The function will now execute with whatever search path is used by its
caller.
</para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
This statement is partially compatible with the <command>ALTER
FUNCTION</command> statement in the SQL standard. The standard allows more
properties of a function to be modified, but does not provide the
ability to rename a function, make a function a security definer,
attach configuration parameter values to a function,
or change the owner, schema, or volatility of a function. The standard also
requires the <literal>RESTRICT</literal> key word, which is optional in
<productname>PostgreSQL</productname>.
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-createfunction"/></member>
<member><xref linkend="sql-dropfunction"/></member>
<member><xref linkend="sql-alterprocedure"/></member>
<member><xref linkend="sql-alterroutine"/></member>
</simplelist>
</refsect1>
</refentry>
|