1CREATE FUNCTION(7)       PostgreSQL 14.3 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 }
17           | [ NOT ] LEAKPROOF
18           | { CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT }
19           | { [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER }
20           | PARALLEL { UNSAFE | RESTRICTED | SAFE }
21           | COST execution_cost
22           | ROWS result_rows
23           | SUPPORT support_function
24           | SET configuration_parameter { TO value | = value | FROM CURRENT }
25           | AS 'definition'
26           | AS 'obj_file', 'link_symbol'
27           | sql_body
28         } ...
29

DESCRIPTION

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

PARAMETERS

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

OVERLOADING

373       PostgreSQL allows function overloading; that is, the same name can be
374       used for several different functions so long as they have distinct
375       input argument types. Whether or not you use it, this capability
376       entails security precautions when calling functions in databases where
377       some users mistrust other users; see Section 10.3.
378
379       Two functions are considered the same if they have the same names and
380       input argument types, ignoring any OUT parameters. Thus for example
381       these declarations conflict:
382
383           CREATE FUNCTION foo(int) ...
384           CREATE FUNCTION foo(int, out text) ...
385
386       Functions that have different argument type lists will not be
387       considered to conflict at creation time, but if defaults are provided
388       they might conflict in use. For example, consider
389
390           CREATE FUNCTION foo(int) ...
391           CREATE FUNCTION foo(int, int default 42) ...
392
393       A call foo(10) will fail due to the ambiguity about which function
394       should be called.
395

NOTES

397       The full SQL type syntax is allowed for declaring a function's
398       arguments and return value. However, parenthesized type modifiers
399       (e.g., the precision field for type numeric) are discarded by CREATE
400       FUNCTION. Thus for example CREATE FUNCTION foo (varchar(10)) ...  is
401       exactly the same as CREATE FUNCTION foo (varchar) ....
402
403       When replacing an existing function with CREATE OR REPLACE FUNCTION,
404       there are restrictions on changing parameter names. You cannot change
405       the name already assigned to any input parameter (although you can add
406       names to parameters that had none before). If there is more than one
407       output parameter, you cannot change the names of the output parameters,
408       because that would change the column names of the anonymous composite
409       type that describes the function's result. These restrictions are made
410       to ensure that existing calls of the function do not stop working when
411       it is replaced.
412
413       If a function is declared STRICT with a VARIADIC argument, the
414       strictness check tests that the variadic array as a whole is non-null.
415       The function will still be called if the array has null elements.
416

EXAMPLES

418       Add two integers using an SQL function:
419
420           CREATE FUNCTION add(integer, integer) RETURNS integer
421               AS 'select $1 + $2;'
422               LANGUAGE SQL
423               IMMUTABLE
424               RETURNS NULL ON NULL INPUT;
425
426       The same function written in a more SQL-conforming style, using
427       argument names and an unquoted body:
428
429           CREATE FUNCTION add(a integer, b integer) RETURNS integer
430               LANGUAGE SQL
431               IMMUTABLE
432               RETURNS NULL ON NULL INPUT
433               RETURN a + b;
434
435       Increment an integer, making use of an argument name, in PL/pgSQL:
436
437           CREATE OR REPLACE FUNCTION increment(i integer) RETURNS integer AS $$
438                   BEGIN
439                           RETURN i + 1;
440                   END;
441           $$ LANGUAGE plpgsql;
442
443       Return a record containing multiple output parameters:
444
445           CREATE FUNCTION dup(in int, out f1 int, out f2 text)
446               AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
447               LANGUAGE SQL;
448
449           SELECT * FROM dup(42);
450
451       You can do the same thing more verbosely with an explicitly named
452       composite type:
453
454           CREATE TYPE dup_result AS (f1 int, f2 text);
455
456           CREATE FUNCTION dup(int) RETURNS dup_result
457               AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
458               LANGUAGE SQL;
459
460           SELECT * FROM dup(42);
461
462       Another way to return multiple columns is to use a TABLE function:
463
464           CREATE FUNCTION dup(int) RETURNS TABLE(f1 int, f2 text)
465               AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
466               LANGUAGE SQL;
467
468           SELECT * FROM dup(42);
469
470       However, a TABLE function is different from the preceding examples,
471       because it actually returns a set of records, not just one record.
472

WRITING SECURITY DEFINER FUNCTIONS SAFELY

474       Because a SECURITY DEFINER function is executed with the privileges of
475       the user that owns it, care is needed to ensure that the function
476       cannot be misused. For security, search_path should be set to exclude
477       any schemas writable by untrusted users. This prevents malicious users
478       from creating objects (e.g., tables, functions, and operators) that
479       mask objects intended to be used by the function. Particularly
480       important in this regard is the temporary-table schema, which is
481       searched first by default, and is normally writable by anyone. A secure
482       arrangement can be obtained by forcing the temporary schema to be
483       searched last. To do this, write pg_temp as the last entry in
484       search_path. This function illustrates safe usage:
485
486           CREATE FUNCTION check_password(uname TEXT, pass TEXT)
487           RETURNS BOOLEAN AS $$
488           DECLARE passed BOOLEAN;
489           BEGIN
490                   SELECT  (pwd = $2) INTO passed
491                   FROM    pwds
492                   WHERE   username = $1;
493
494                   RETURN passed;
495           END;
496           $$  LANGUAGE plpgsql
497               SECURITY DEFINER
498               -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
499               SET search_path = admin, pg_temp;
500
501       This function's intention is to access a table admin.pwds. But without
502       the SET clause, or with a SET clause mentioning only admin, the
503       function could be subverted by creating a temporary table named pwds.
504
505       Before PostgreSQL version 8.3, the SET clause was not available, and so
506       older functions may contain rather complicated logic to save, set, and
507       restore search_path. The SET clause is far easier to use for this
508       purpose.
509
510       Another point to keep in mind is that by default, execute privilege is
511       granted to PUBLIC for newly created functions (see Section 5.7 for more
512       information). Frequently you will wish to restrict use of a security
513       definer function to only some users. To do that, you must revoke the
514       default PUBLIC privileges and then grant execute privilege selectively.
515       To avoid having a window where the new function is accessible to all,
516       create it and set the privileges within a single transaction. For
517       example:
518
519           BEGIN;
520           CREATE FUNCTION check_password(uname TEXT, pass TEXT) ... SECURITY DEFINER;
521           REVOKE ALL ON FUNCTION check_password(uname TEXT, pass TEXT) FROM PUBLIC;
522           GRANT EXECUTE ON FUNCTION check_password(uname TEXT, pass TEXT) TO admins;
523           COMMIT;
524

COMPATIBILITY

526       A CREATE FUNCTION command is defined in the SQL standard. The
527       PostgreSQL implementation can be used in a compatible way but has many
528       extensions. Conversely, the SQL standard specifies a number of optional
529       features that are not implemented in PostgreSQL.
530
531       The following are important compatibility issues:
532
533       •   OR REPLACE is a PostgreSQL extension.
534
535       •   For compatibility with some other database systems, argmode can be
536           written either before or after argname. But only the first way is
537           standard-compliant.
538
539       •   For parameter defaults, the SQL standard specifies only the syntax
540           with the DEFAULT key word. The syntax with = is used in T-SQL and
541           Firebird.
542
543       •   The SETOF modifier is a PostgreSQL extension.
544
545       •   Only SQL is standardized as a language.
546
547       •   All other attributes except CALLED ON NULL INPUT and RETURNS NULL
548           ON NULL INPUT are not standardized.
549
550       •   For the body of LANGUAGE SQL functions, the SQL standard only
551           specifies the sql_body form.
552
553       Simple LANGUAGE SQL functions can be written in a way that is both
554       standard-conforming and portable to other implementations. More complex
555       functions using advanced features, optimization attributes, or other
556       languages will necessarily be specific to PostgreSQL in a significant
557       way.
558

SEE ALSO

560       ALTER FUNCTION (ALTER_FUNCTION(7)), DROP FUNCTION (DROP_FUNCTION(7)),
561       GRANT(7), LOAD(7), REVOKE(7)
562
563
564
565PostgreSQL 14.3                      2022                   CREATE FUNCTION(7)
Impressum