1CREATE FUNCTION(7)       PostgreSQL 10.7 Documentation      CREATE FUNCTION(7)
2
3
4

NAME

6       CREATE_FUNCTION - define a new function
7

SYNOPSIS

9       CREATE [ OR REPLACE ] FUNCTION
10           name ( [ [ argmode ] [ argname ] argtype [ { DEFAULT | = } default_expr ] [, ...] ] )
11           [ RETURNS rettype
12             | RETURNS TABLE ( column_name column_type [, ...] ) ]
13         { LANGUAGE lang_name
14           | TRANSFORM { FOR TYPE type_name } [, ... ]
15           | WINDOW
16           | IMMUTABLE | STABLE | VOLATILE | [ NOT ] LEAKPROOF
17           | CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
18           | [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
19           | PARALLEL { UNSAFE | RESTRICTED | SAFE }
20           | COST execution_cost
21           | ROWS result_rows
22           | SET configuration_parameter { TO value | = value | FROM CURRENT }
23           | AS 'definition'
24           | AS 'obj_file', 'link_symbol'
25         } ...
26           [ WITH ( attribute [, ...] ) ]
27

DESCRIPTION

29       CREATE FUNCTION defines a new function.  CREATE OR REPLACE FUNCTION
30       will either create a new function, or replace an existing definition.
31       To be able to define a function, the user must have the USAGE privilege
32       on the language.
33
34       If a schema name is included, then the function is created in the
35       specified schema. Otherwise it is created in the current schema. The
36       name of the new function must not match any existing function with the
37       same input argument types in the same schema. However, functions of
38       different argument types can share a name (this is called overloading).
39
40       To replace the current definition of an existing function, use CREATE
41       OR REPLACE FUNCTION. It is not possible to change the name or argument
42       types of a function this way (if you tried, you would actually be
43       creating a new, distinct function). Also, CREATE OR REPLACE FUNCTION
44       will not let you change the return type of an existing function. To do
45       that, you must drop and recreate the function. (When using OUT
46       parameters, that means you cannot change the types of any OUT
47       parameters except by dropping the function.)
48
49       When CREATE OR REPLACE FUNCTION is used to replace an existing
50       function, the ownership and permissions of the function do not change.
51       All other function properties are assigned the values specified or
52       implied in the command. You must own the function to replace it (this
53       includes being a member of the owning role).
54
55       If you drop and then recreate a function, the new function is not the
56       same entity as the old; you will have to drop existing rules, views,
57       triggers, etc. that refer to the old function. Use CREATE OR REPLACE
58       FUNCTION to change a function definition without breaking objects that
59       refer to the function. Also, ALTER FUNCTION can be used to change most
60       of the auxiliary properties of an existing function.
61
62       The user that creates the function becomes the owner of the function.
63
64       To be able to create a function, you must have USAGE privilege on the
65       argument types and the return type.
66

PARAMETERS

68       name
69           The name (optionally schema-qualified) of the function to create.
70
71       argmode
72           The mode of an argument: IN, OUT, INOUT, or VARIADIC. If omitted,
73           the default is IN. Only OUT arguments can follow a VARIADIC one.
74           Also, OUT and INOUT arguments cannot be used together with the
75           RETURNS TABLE notation.
76
77       argname
78           The name of an argument. Some languages (including SQL and
79           PL/pgSQL) let you use the name in the function body. For other
80           languages the name of an input argument is just extra
81           documentation, so far as the function itself is concerned; but you
82           can use input argument names when calling a function to improve
83           readability (see Section 4.3). In any case, the name of an output
84           argument is significant, because it defines the column name in the
85           result row type. (If you omit the name for an output argument, the
86           system will choose a default column name.)
87
88       argtype
89           The data type(s) of the function's arguments (optionally
90           schema-qualified), if any. The argument types can be base,
91           composite, or domain types, or can reference the type of a table
92           column.
93
94           Depending on the implementation language it might also be allowed
95           to specify “pseudo-types” such as cstring. Pseudo-types indicate
96           that the actual argument type is either incompletely specified, or
97           outside the set of ordinary SQL data types.
98
99           The type of a column is referenced by writing
100           table_name.column_name%TYPE. Using this feature can sometimes help
101           make a function independent of changes to the definition of a
102           table.
103
104       default_expr
105           An expression to be used as default value if the parameter is not
106           specified. The expression has to be coercible to the argument type
107           of the parameter. Only input (including INOUT) parameters can have
108           a default value. All input parameters following a parameter with a
109           default value must have default values as well.
110
111       rettype
112           The return data type (optionally schema-qualified). The return type
113           can be a base, composite, or domain type, or can reference the type
114           of a table column. Depending on the implementation language it
115           might also be allowed to specify “pseudo-types” such as cstring. If
116           the function is not supposed to return a value, specify void as the
117           return type.
118
119           When there are OUT or INOUT parameters, the RETURNS clause can be
120           omitted. If present, it must agree with the result type implied by
121           the output parameters: RECORD if there are multiple output
122           parameters, or the same type as the single output parameter.
123
124           The SETOF modifier indicates that the function will return a set of
125           items, rather than a single item.
126
127           The type of a column is referenced by writing
128           table_name.column_name%TYPE.
129
130       column_name
131           The name of an output column in the RETURNS TABLE syntax. This is
132           effectively another way of declaring a named OUT parameter, except
133           that RETURNS TABLE also implies RETURNS SETOF.
134
135       column_type
136           The data type of an output column in the RETURNS TABLE syntax.
137
138       lang_name
139           The name of the language that the function is implemented in. It
140           can be sql, c, internal, or the name of a user-defined procedural
141           language, e.g.  plpgsql. Enclosing the name in single quotes is
142           deprecated and requires matching case.
143
144       TRANSFORM { FOR TYPE type_name } [, ... ] }
145           Lists which transforms a call to the function should apply.
146           Transforms convert between SQL types and language-specific data
147           types; see CREATE TRANSFORM (CREATE_TRANSFORM(7)). Procedural
148           language implementations usually have hardcoded knowledge of the
149           built-in types, so those don't need to be listed here. If a
150           procedural language implementation does not know how to handle a
151           type and no transform is supplied, it will fall back to a default
152           behavior for converting data types, but this depends on the
153           implementation.
154
155       WINDOW
156           WINDOW indicates that the function is a window function rather than
157           a plain function. This is currently only useful for functions
158           written in C. The WINDOW attribute cannot be changed when replacing
159           an existing function definition.
160
161       IMMUTABLE
162       STABLE
163       VOLATILE
164           These attributes inform the query optimizer about the behavior of
165           the function. At most one choice can be specified. If none of these
166           appear, VOLATILE is the default assumption.
167
168           IMMUTABLE indicates that the function cannot modify the database
169           and always returns the same result when given the same argument
170           values; that is, it does not do database lookups or otherwise use
171           information not directly present in its argument list. If this
172           option is given, any call of the function with all-constant
173           arguments can be immediately replaced with the function value.
174
175           STABLE indicates that the function cannot modify the database, and
176           that within a single table scan it will consistently return the
177           same result for the same argument values, but that its result could
178           change across SQL statements. This is the appropriate selection for
179           functions whose results depend on database lookups, parameter
180           variables (such as the current time zone), etc. (It is
181           inappropriate for AFTER triggers that wish to query rows modified
182           by the current command.) Also note that the current_timestamp
183           family of functions qualify as stable, since their values do not
184           change within a transaction.
185
186           VOLATILE indicates that the function value can change even within a
187           single table scan, so no optimizations can be made. Relatively few
188           database functions are volatile in this sense; some examples are
189           random(), currval(), timeofday(). But note that any function that
190           has side-effects must be classified volatile, even if its result is
191           quite predictable, to prevent calls from being optimized away; an
192           example is setval().
193
194           For additional details see Section 37.6.
195
196       LEAKPROOF
197           LEAKPROOF indicates that the function has no side effects. It
198           reveals no information about its arguments other than by its return
199           value. For example, a function which throws an error message for
200           some argument values but not others, or which includes the argument
201           values in any error message, is not leakproof. This affects how the
202           system executes queries against views created with the
203           security_barrier option or tables with row level security enabled.
204           The system will enforce conditions from security policies and
205           security barrier views before any user-supplied conditions from the
206           query itself that contain non-leakproof functions, in order to
207           prevent the inadvertent exposure of data. Functions and operators
208           marked as leakproof are assumed to be trustworthy, and may be
209           executed before conditions from security policies and security
210           barrier views. In addition, functions which do not take arguments
211           or which are not passed any arguments from the security barrier
212           view or table do not have to be marked as leakproof to be executed
213           before security conditions. See CREATE VIEW (CREATE_VIEW(7)) and
214           Section 40.5. This option can only be set by the superuser.
215
216       CALLED ON NULL INPUT
217       RETURNS NULL ON NULL INPUT
218       STRICT
219           CALLED ON NULL INPUT (the default) indicates that the function will
220           be called normally when some of its arguments are null. It is then
221           the function author's responsibility to check for null values if
222           necessary and respond appropriately.
223
224           RETURNS NULL ON NULL INPUT or STRICT indicates that the function
225           always returns null whenever any of its arguments are null. If this
226           parameter is specified, the function is not executed when there are
227           null arguments; instead a null result is assumed automatically.
228
229       [EXTERNAL] SECURITY INVOKER
230       [EXTERNAL] SECURITY DEFINER
231           SECURITY INVOKER indicates that the function is to be executed with
232           the privileges of the user that calls it. That is the default.
233           SECURITY DEFINER specifies that the function is to be executed with
234           the privileges of the user that owns it.
235
236           The key word EXTERNAL is allowed for SQL conformance, but it is
237           optional since, unlike in SQL, this feature applies to all
238           functions not only external ones.
239
240       PARALLEL
241           PARALLEL UNSAFE indicates that the function can't be executed in
242           parallel mode and the presence of such a function in an SQL
243           statement forces a serial execution plan. This is the default.
244           PARALLEL RESTRICTED indicates that the function can be executed in
245           parallel mode, but the execution is restricted to parallel group
246           leader.  PARALLEL SAFE indicates that the function is safe to run
247           in parallel mode without restriction.
248
249           Functions should be labeled parallel unsafe if they modify any
250           database state, or if they make changes to the transaction such as
251           using sub-transactions, or if they access sequences or attempt to
252           make persistent changes to settings (e.g.  setval). They should be
253           labeled as parallel restricted if they access temporary tables,
254           client connection state, cursors, prepared statements, or
255           miscellaneous backend-local state which the system cannot
256           synchronize in parallel mode (e.g.  setseed cannot be executed
257           other than by the group leader because a change made by another
258           process would not be reflected in the leader). In general, if a
259           function is labeled as being safe when it is restricted or unsafe,
260           or if it is labeled as being restricted when it is in fact unsafe,
261           it may throw errors or produce wrong answers when used in a
262           parallel query. C-language functions could in theory exhibit
263           totally undefined behavior if mislabeled, since there is no way for
264           the system to protect itself against arbitrary C code, but in most
265           likely cases the result will be no worse than for any other
266           function. If in doubt, functions should be labeled as UNSAFE, which
267           is the default.
268
269       execution_cost
270           A positive number giving the estimated execution cost for the
271           function, in units of cpu_operator_cost. If the function returns a
272           set, this is the cost per returned row. If the cost is not
273           specified, 1 unit is assumed for C-language and internal functions,
274           and 100 units for functions in all other languages. Larger values
275           cause the planner to try to avoid evaluating the function more
276           often than necessary.
277
278       result_rows
279           A positive number giving the estimated number of rows that the
280           planner should expect the function to return. This is only allowed
281           when the function is declared to return a set. The default
282           assumption is 1000 rows.
283
284       configuration_parameter
285       value
286           The SET clause causes the specified configuration parameter to be
287           set to the specified value when the function is entered, and then
288           restored to its prior value when the function exits.  SET FROM
289           CURRENT saves the value of the parameter that is current when
290           CREATE FUNCTION is executed as the value to be applied when the
291           function is entered.
292
293           If a SET clause is attached to a function, then the effects of a
294           SET LOCAL command executed inside the function for the same
295           variable are restricted to the function: the configuration
296           parameter's prior value is still restored at function exit.
297           However, an ordinary SET command (without LOCAL) overrides the SET
298           clause, much as it would do for a previous SET LOCAL command: the
299           effects of such a command will persist after function exit, unless
300           the current transaction is rolled back.
301
302           See SET(7) and Chapter 19 for more information about allowed
303           parameter names and values.
304
305       definition
306           A string constant defining the function; the meaning depends on the
307           language. It can be an internal function name, the path to an
308           object file, an SQL command, or text in a procedural language.
309
310           It is often helpful to use dollar quoting (see Section 4.1.2.4) to
311           write the function definition string, rather than the normal single
312           quote syntax. Without dollar quoting, any single quotes or
313           backslashes in the function definition must be escaped by doubling
314           them.
315
316       obj_file, link_symbol
317           This form of the AS clause is used for dynamically loadable C
318           language functions when the function name in the C language source
319           code is not the same as the name of the SQL function. The string
320           obj_file is the name of the shared library file containing the
321           compiled C function, and is interpreted as for the LOAD(7) command.
322           The string link_symbol is the function's link symbol, that is, the
323           name of the function in the C language source code. If the link
324           symbol is omitted, it is assumed to be the same as the name of the
325           SQL function being defined. The C names of all functions must be
326           different, so you must give overloaded C functions different C
327           names (for example, use the argument types as part of the C names).
328
329           When repeated CREATE FUNCTION calls refer to the same object file,
330           the file is only loaded once per session. To unload and reload the
331           file (perhaps during development), start a new session.
332
333       attribute
334           The historical way to specify optional pieces of information about
335           the function. The following attributes can appear here:
336
337           isStrict
338               Equivalent to STRICT or RETURNS NULL ON NULL INPUT.
339
340           isCachable
341               isCachable is an obsolete equivalent of IMMUTABLE; it's still
342               accepted for backwards-compatibility reasons.
343
344           Attribute names are not case-sensitive.
345
346       Refer to Section 37.3 for further information on writing functions.
347

OVERLOADING

349       PostgreSQL allows function overloading; that is, the same name can be
350       used for several different functions so long as they have distinct
351       input argument types. Whether or not you use it, this capability
352       entails security precautions when calling functions in databases where
353       some users mistrust other users; see Section 10.3.
354
355       Two functions are considered the same if they have the same names and
356       input argument types, ignoring any OUT parameters. Thus for example
357       these declarations conflict:
358
359           CREATE FUNCTION foo(int) ...
360           CREATE FUNCTION foo(int, out text) ...
361
362       Functions that have different argument type lists will not be
363       considered to conflict at creation time, but if defaults are provided
364       they might conflict in use. For example, consider
365
366           CREATE FUNCTION foo(int) ...
367           CREATE FUNCTION foo(int, int default 42) ...
368
369       A call foo(10) will fail due to the ambiguity about which function
370       should be called.
371

NOTES

373       The full SQL type syntax is allowed for declaring a function's
374       arguments and return value. However, parenthesized type modifiers
375       (e.g., the precision field for type numeric) are discarded by CREATE
376       FUNCTION. Thus for example CREATE FUNCTION foo (varchar(10)) ...  is
377       exactly the same as CREATE FUNCTION foo (varchar) ....
378
379       When replacing an existing function with CREATE OR REPLACE FUNCTION,
380       there are restrictions on changing parameter names. You cannot change
381       the name already assigned to any input parameter (although you can add
382       names to parameters that had none before). If there is more than one
383       output parameter, you cannot change the names of the output parameters,
384       because that would change the column names of the anonymous composite
385       type that describes the function's result. These restrictions are made
386       to ensure that existing calls of the function do not stop working when
387       it is replaced.
388
389       If a function is declared STRICT with a VARIADIC argument, the
390       strictness check tests that the variadic array as a whole is non-null.
391       The function will still be called if the array has null elements.
392

EXAMPLES

394       Here are some trivial examples to help you get started. For more
395       information and examples, see Section 37.3.
396
397           CREATE FUNCTION add(integer, integer) RETURNS integer
398               AS 'select $1 + $2;'
399               LANGUAGE SQL
400               IMMUTABLE
401               RETURNS NULL ON NULL INPUT;
402
403       Increment an integer, making use of an argument name, in PL/pgSQL:
404
405           CREATE OR REPLACE FUNCTION increment(i integer) RETURNS integer AS $$
406                   BEGIN
407                           RETURN i + 1;
408                   END;
409           $$ LANGUAGE plpgsql;
410
411       Return a record containing multiple output parameters:
412
413           CREATE FUNCTION dup(in int, out f1 int, out f2 text)
414               AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
415               LANGUAGE SQL;
416
417           SELECT * FROM dup(42);
418
419       You can do the same thing more verbosely with an explicitly named
420       composite type:
421
422           CREATE TYPE dup_result AS (f1 int, f2 text);
423
424           CREATE FUNCTION dup(int) RETURNS dup_result
425               AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
426               LANGUAGE SQL;
427
428           SELECT * FROM dup(42);
429
430       Another way to return multiple columns is to use a TABLE function:
431
432           CREATE FUNCTION dup(int) RETURNS TABLE(f1 int, f2 text)
433               AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
434               LANGUAGE SQL;
435
436           SELECT * FROM dup(42);
437
438       However, a TABLE function is different from the preceding examples,
439       because it actually returns a set of records, not just one record.
440

WRITING SECURITY DEFINER FUNCTIONS SAFELY

442       Because a SECURITY DEFINER function is executed with the privileges of
443       the user that owns it, care is needed to ensure that the function
444       cannot be misused. For security, search_path should be set to exclude
445       any schemas writable by untrusted users. This prevents malicious users
446       from creating objects (e.g., tables, functions, and operators) that
447       mask objects intended to be used by the function. Particularly
448       important in this regard is the temporary-table schema, which is
449       searched first by default, and is normally writable by anyone. A secure
450       arrangement can be obtained by forcing the temporary schema to be
451       searched last. To do this, write pg_temp as the last entry in
452       search_path. This function illustrates safe usage:
453
454           CREATE FUNCTION check_password(uname TEXT, pass TEXT)
455           RETURNS BOOLEAN AS $$
456           DECLARE passed BOOLEAN;
457           BEGIN
458                   SELECT  (pwd = $2) INTO passed
459                   FROM    pwds
460                   WHERE   username = $1;
461
462                   RETURN passed;
463           END;
464           $$  LANGUAGE plpgsql
465               SECURITY DEFINER
466               -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
467               SET search_path = admin, pg_temp;
468
469       This function's intention is to access a table admin.pwds. But without
470       the SET clause, or with a SET clause mentioning only admin, the
471       function could be subverted by creating a temporary table named pwds.
472
473       Before PostgreSQL version 8.3, the SET clause was not available, and so
474       older functions may contain rather complicated logic to save, set, and
475       restore search_path. The SET clause is far easier to use for this
476       purpose.
477
478       Another point to keep in mind is that by default, execute privilege is
479       granted to PUBLIC for newly created functions (see GRANT(7) for more
480       information). Frequently you will wish to restrict use of a security
481       definer function to only some users. To do that, you must revoke the
482       default PUBLIC privileges and then grant execute privilege selectively.
483       To avoid having a window where the new function is accessible to all,
484       create it and set the privileges within a single transaction. For
485       example:
486
487           BEGIN;
488           CREATE FUNCTION check_password(uname TEXT, pass TEXT) ... SECURITY DEFINER;
489           REVOKE ALL ON FUNCTION check_password(uname TEXT, pass TEXT) FROM PUBLIC;
490           GRANT EXECUTE ON FUNCTION check_password(uname TEXT, pass TEXT) TO admins;
491           COMMIT;
492

COMPATIBILITY

494       A CREATE FUNCTION command is defined in SQL:1999 and later. The
495       PostgreSQL version is similar but not fully compatible. The attributes
496       are not portable, neither are the different available languages.
497
498       For compatibility with some other database systems, argmode can be
499       written either before or after argname. But only the first way is
500       standard-compliant.
501
502       For parameter defaults, the SQL standard specifies only the syntax with
503       the DEFAULT key word. The syntax with = is used in T-SQL and Firebird.
504

SEE ALSO

506       ALTER FUNCTION (ALTER_FUNCTION(7)), DROP FUNCTION (DROP_FUNCTION(7)),
507       GRANT(7), LOAD(7), REVOKE(7)
508
509
510
511PostgreSQL 10.7                      2019                   CREATE FUNCTION(7)
Impressum