1CREATE FUNCTION(7)      PostgreSQL 9.2.24 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           | WINDOW
15           | IMMUTABLE | STABLE | VOLATILE | [ NOT ] LEAKPROOF
16           | CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
17           | [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
18           | COST execution_cost
19           | ROWS result_rows
20           | SET configuration_parameter { TO value | = value | FROM CURRENT }
21           | AS 'definition'
22           | AS 'obj_file', 'link_symbol'
23         } ...
24           [ WITH ( attribute [, ...] ) ]
25

DESCRIPTION

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

PARAMETERS

66       name
67           The name (optionally schema-qualified) of the function to create.
68
69       argmode
70           The mode of an argument: IN, OUT, INOUT, or VARIADIC. If omitted,
71           the default is IN. Only OUT arguments can follow a VARIADIC one.
72           Also, OUT and INOUT arguments cannot be used together with the
73           RETURNS TABLE notation.
74
75       argname
76           The name of an argument. Some languages (including SQL and
77           PL/pgSQL) let you use the name in the function body. For other
78           languages the name of an input argument is just extra
79           documentation, so far as the function itself is concerned; but you
80           can use input argument names when calling a function to improve
81           readability (see Section 4.3, “Calling Functions”, in the
82           documentation). In any case, the name of an output argument is
83           significant, because it defines the column name in the result row
84           type. (If you omit the name for an output argument, the system will
85           choose a default column name.)
86
87       argtype
88           The data type(s) of the function's arguments (optionally
89           schema-qualified), if any. The argument types can be base,
90           composite, or domain types, or can reference the type of a table
91           column.
92
93           Depending on the implementation language it might also be allowed
94           to specify “pseudotypes” such as cstring. Pseudotypes indicate that
95           the actual argument type is either incompletely specified, or
96           outside the set of ordinary SQL data types.
97
98           The type of a column is referenced by writing
99           table_name.column_name%TYPE. Using this feature can sometimes help
100           make a function independent of changes to the definition of a
101           table.
102
103       default_expr
104           An expression to be used as default value if the parameter is not
105           specified. The expression has to be coercible to the argument type
106           of the parameter. Only input (including INOUT) parameters can have
107           a default value. All input parameters following a parameter with a
108           default value must have default values as well.
109
110       rettype
111           The return data type (optionally schema-qualified). The return type
112           can be a base, composite, or domain type, or can reference the type
113           of a table column. Depending on the implementation language it
114           might also be allowed to specify “pseudotypes” such as cstring. If
115           the function is not supposed to return a value, specify void as the
116           return type.
117
118           When there are OUT or INOUT parameters, the RETURNS clause can be
119           omitted. If present, it must agree with the result type implied by
120           the output parameters: RECORD if there are multiple output
121           parameters, or the same type as the single output parameter.
122
123           The SETOF modifier indicates that the function will return a set of
124           items, rather than a single item.
125
126           The type of a column is referenced by writing
127           table_name.column_name%TYPE.
128
129       column_name
130           The name of an output column in the RETURNS TABLE syntax. This is
131           effectively another way of declaring a named OUT parameter, except
132           that RETURNS TABLE also implies RETURNS SETOF.
133
134       column_type
135           The data type of an output column in the RETURNS TABLE syntax.
136
137       lang_name
138           The name of the language that the function is implemented in. Can
139           be SQL, C, internal, or the name of a user-defined procedural
140           language. For backward compatibility, the name can be enclosed by
141           single quotes.
142
143       WINDOW
144           WINDOW indicates that the function is a window function rather than
145           a plain function. This is currently only useful for functions
146           written in C. The WINDOW attribute cannot be changed when replacing
147           an existing function definition.
148
149       IMMUTABLE, STABLE, VOLATILE
150           These attributes inform the query optimizer about the behavior of
151           the function. At most one choice can be specified. If none of these
152           appear, VOLATILE is the default assumption.
153
154           IMMUTABLE indicates that the function cannot modify the database
155           and always returns the same result when given the same argument
156           values; that is, it does not do database lookups or otherwise use
157           information not directly present in its argument list. If this
158           option is given, any call of the function with all-constant
159           arguments can be immediately replaced with the function value.
160
161           STABLE indicates that the function cannot modify the database, and
162           that within a single table scan it will consistently return the
163           same result for the same argument values, but that its result could
164           change across SQL statements. This is the appropriate selection for
165           functions whose results depend on database lookups, parameter
166           variables (such as the current time zone), etc. (It is
167           inappropriate for AFTER triggers that wish to query rows modified
168           by the current command.) Also note that the current_timestamp
169           family of functions qualify as stable, since their values do not
170           change within a transaction.
171
172           VOLATILE indicates that the function value can change even within a
173           single table scan, so no optimizations can be made. Relatively few
174           database functions are volatile in this sense; some examples are
175           random(), currval(), timeofday(). But note that any function that
176           has side-effects must be classified volatile, even if its result is
177           quite predictable, to prevent calls from being optimized away; an
178           example is setval().
179
180           For additional details see Section 35.6, “Function Volatility
181           Categories”, in the documentation.
182
183       LEAKPROOF
184           LEAKPROOF indicates that the function has no side effects. It
185           reveals no information about its arguments other than by its return
186           value. For example, a function which throws an error message for
187           some argument values but not others, or which includes the argument
188           values in any error message, is not leakproof. The query planner
189           may push leakproof functions (but not others) into views created
190           with the security_barrier option. See CREATE VIEW (CREATE_VIEW(7))
191           and Section 37.4, “Rules and Privileges”, in the documentation.
192           This option can only be set by the superuser.
193
194       CALLED ON NULL INPUT, RETURNS NULL ON NULL INPUT, STRICT
195           CALLED ON NULL INPUT (the default) indicates that the function will
196           be called normally when some of its arguments are null. It is then
197           the function author's responsibility to check for null values if
198           necessary and respond appropriately.
199
200           RETURNS NULL ON NULL INPUT or STRICT indicates that the function
201           always returns null whenever any of its arguments are null. If this
202           parameter is specified, the function is not executed when there are
203           null arguments; instead a null result is assumed automatically.
204
205       [EXTERNAL] SECURITY INVOKER, [EXTERNAL] SECURITY DEFINER
206           SECURITY INVOKER indicates that the function is to be executed with
207           the privileges of the user that calls it. That is the default.
208           SECURITY DEFINER specifies that the function is to be executed with
209           the privileges of the user that created it.
210
211           The key word EXTERNAL is allowed for SQL conformance, but it is
212           optional since, unlike in SQL, this feature applies to all
213           functions not only external ones.
214
215       execution_cost
216           A positive number giving the estimated execution cost for the
217           function, in units of cpu_operator_cost. If the function returns a
218           set, this is the cost per returned row. If the cost is not
219           specified, 1 unit is assumed for C-language and internal functions,
220           and 100 units for functions in all other languages. Larger values
221           cause the planner to try to avoid evaluating the function more
222           often than necessary.
223
224       result_rows
225           A positive number giving the estimated number of rows that the
226           planner should expect the function to return. This is only allowed
227           when the function is declared to return a set. The default
228           assumption is 1000 rows.
229
230       configuration_parameter, value
231           The SET clause causes the specified configuration parameter to be
232           set to the specified value when the function is entered, and then
233           restored to its prior value when the function exits.  SET FROM
234           CURRENT saves the value of the parameter that is current when
235           CREATE FUNCTION is executed as the value to be applied when the
236           function is entered.
237
238           If a SET clause is attached to a function, then the effects of a
239           SET LOCAL command executed inside the function for the same
240           variable are restricted to the function: the configuration
241           parameter's prior value is still restored at function exit.
242           However, an ordinary SET command (without LOCAL) overrides the SET
243           clause, much as it would do for a previous SET LOCAL command: the
244           effects of such a command will persist after function exit, unless
245           the current transaction is rolled back.
246
247           See SET(7) and Chapter 18, Server Configuration, in the
248           documentation for more information about allowed parameter names
249           and values.
250
251       definition
252           A string constant defining the function; the meaning depends on the
253           language. It can be an internal function name, the path to an
254           object file, an SQL command, or text in a procedural language.
255
256           It is often helpful to use dollar quoting (see Section 4.1.2.4,
257           “Dollar-quoted String Constants”, in the documentation) to write
258           the function definition string, rather than the normal single quote
259           syntax. Without dollar quoting, any single quotes or backslashes in
260           the function definition must be escaped by doubling them.
261
262       obj_file, link_symbol
263           This form of the AS clause is used for dynamically loadable C
264           language functions when the function name in the C language source
265           code is not the same as the name of the SQL function. The string
266           obj_file is the name of the file containing the dynamically
267           loadable object, and link_symbol is the function's link symbol,
268           that is, the name of the function in the C language source code. If
269           the link symbol is omitted, it is assumed to be the same as the
270           name of the SQL function being defined.
271
272           When repeated CREATE FUNCTION calls refer to the same object file,
273           the file is only loaded once per session. To unload and reload the
274           file (perhaps during development), start a new session.
275
276       attribute
277           The historical way to specify optional pieces of information about
278           the function. The following attributes can appear here:
279
280           isStrict
281               Equivalent to STRICT or RETURNS NULL ON NULL INPUT.
282
283           isCachable
284               isCachable is an obsolete equivalent of IMMUTABLE; it's still
285               accepted for backwards-compatibility reasons.
286
287           Attribute names are not case-sensitive.
288
289       Refer to Section 35.3, “User-defined Functions”, in the documentation
290       for further information on writing functions.
291

OVERLOADING

293       PostgreSQL allows function overloading; that is, the same name can be
294       used for several different functions so long as they have distinct
295       input argument types. However, the C names of all functions must be
296       different, so you must give overloaded C functions different C names
297       (for example, use the argument types as part of the C names).
298
299       Two functions are considered the same if they have the same names and
300       input argument types, ignoring any OUT parameters. Thus for example
301       these declarations conflict:
302
303           CREATE FUNCTION foo(int) ...
304           CREATE FUNCTION foo(int, out text) ...
305
306       Functions that have different argument type lists will not be
307       considered to conflict at creation time, but if defaults are provided
308       they might conflict in use. For example, consider
309
310           CREATE FUNCTION foo(int) ...
311           CREATE FUNCTION foo(int, int default 42) ...
312
313       A call foo(10) will fail due to the ambiguity about which function
314       should be called.
315

NOTES

317       The full SQL type syntax is allowed for declaring a function's
318       arguments and return value. However, parenthesized type modifiers
319       (e.g., the precision field for type numeric) are discarded by CREATE
320       FUNCTION. Thus for example CREATE FUNCTION foo (varchar(10)) ...  is
321       exactly the same as CREATE FUNCTION foo (varchar) ....
322
323       When replacing an existing function with CREATE OR REPLACE FUNCTION,
324       there are restrictions on changing parameter names. You cannot change
325       the name already assigned to any input parameter (although you can add
326       names to parameters that had none before). If there is more than one
327       output parameter, you cannot change the names of the output parameters,
328       because that would change the column names of the anonymous composite
329       type that describes the function's result. These restrictions are made
330       to ensure that existing calls of the function do not stop working when
331       it is replaced.
332
333       If a function is declared STRICT with a VARIADIC argument, the
334       strictness check tests that the variadic array as a whole is non-null.
335       The function will still be called if the array has null elements.
336

EXAMPLES

338       Here are some trivial examples to help you get started. For more
339       information and examples, see Section 35.3, “User-defined Functions”,
340       in the documentation.
341
342           CREATE FUNCTION add(integer, integer) RETURNS integer
343               AS 'select $1 + $2;'
344               LANGUAGE SQL
345               IMMUTABLE
346               RETURNS NULL ON NULL INPUT;
347
348       Increment an integer, making use of an argument name, in PL/pgSQL:
349
350           CREATE OR REPLACE FUNCTION increment(i integer) RETURNS integer AS $$
351                   BEGIN
352                           RETURN i + 1;
353                   END;
354           $$ LANGUAGE plpgsql;
355
356       Return a record containing multiple output parameters:
357
358           CREATE FUNCTION dup(in int, out f1 int, out f2 text)
359               AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
360               LANGUAGE SQL;
361
362           SELECT * FROM dup(42);
363
364       You can do the same thing more verbosely with an explicitly named
365       composite type:
366
367           CREATE TYPE dup_result AS (f1 int, f2 text);
368
369           CREATE FUNCTION dup(int) RETURNS dup_result
370               AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
371               LANGUAGE SQL;
372
373           SELECT * FROM dup(42);
374
375       Another way to return multiple columns is to use a TABLE function:
376
377           CREATE FUNCTION dup(int) RETURNS TABLE(f1 int, f2 text)
378               AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
379               LANGUAGE SQL;
380
381           SELECT * FROM dup(42);
382
383       However, a TABLE function is different from the preceding examples,
384       because it actually returns a set of records, not just one record.
385

WRITING SECURITY DEFINER FUNCTIONS SAFELY

387       Because a SECURITY DEFINER function is executed with the privileges of
388       the user that created it, care is needed to ensure that the function
389       cannot be misused. For security, search_path should be set to exclude
390       any schemas writable by untrusted users. This prevents malicious users
391       from creating objects that mask objects used by the function.
392       Particularly important in this regard is the temporary-table schema,
393       which is searched first by default, and is normally writable by anyone.
394       A secure arrangement can be had by forcing the temporary schema to be
395       searched last. To do this, write pg_temp as the last entry in
396       search_path. This function illustrates safe usage:
397
398           CREATE FUNCTION check_password(uname TEXT, pass TEXT)
399           RETURNS BOOLEAN AS $$
400           DECLARE passed BOOLEAN;
401           BEGIN
402                   SELECT  (pwd = $2) INTO passed
403                   FROM    pwds
404                   WHERE   username = $1;
405
406                   RETURN passed;
407           END;
408           $$  LANGUAGE plpgsql
409               SECURITY DEFINER
410               -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
411               SET search_path = admin, pg_temp;
412
413       Before PostgreSQL version 8.3, the SET option was not available, and so
414       older functions may contain rather complicated logic to save, set, and
415       restore search_path. The SET option is far easier to use for this
416       purpose.
417
418       Another point to keep in mind is that by default, execute privilege is
419       granted to PUBLIC for newly created functions (see GRANT(7) for more
420       information). Frequently you will wish to restrict use of a security
421       definer function to only some users. To do that, you must revoke the
422       default PUBLIC privileges and then grant execute privilege selectively.
423       To avoid having a window where the new function is accessible to all,
424       create it and set the privileges within a single transaction. For
425       example:
426
427           BEGIN;
428           CREATE FUNCTION check_password(uname TEXT, pass TEXT) ... SECURITY DEFINER;
429           REVOKE ALL ON FUNCTION check_password(uname TEXT, pass TEXT) FROM PUBLIC;
430           GRANT EXECUTE ON FUNCTION check_password(uname TEXT, pass TEXT) TO admins;
431           COMMIT;
432

COMPATIBILITY

434       A CREATE FUNCTION command is defined in SQL:1999 and later. The
435       PostgreSQL version is similar but not fully compatible. The attributes
436       are not portable, neither are the different available languages.
437
438       For compatibility with some other database systems, argmode can be
439       written either before or after argname. But only the first way is
440       standard-compliant.
441
442       The SQL standard does not specify parameter defaults. The syntax with
443       the DEFAULT key word is from Oracle, and it is somewhat in the spirit
444       of the standard: SQL/PSM uses it for variable default values. The
445       syntax with = is used in T-SQL and Firebird.
446

SEE ALSO

448       ALTER FUNCTION (ALTER_FUNCTION(7)), DROP FUNCTION (DROP_FUNCTION(7)),
449       GRANT(7), LOAD(7), REVOKE(7), createlang(1)
450
451
452
453PostgreSQL 9.2.24                 2017-11-06                CREATE FUNCTION(7)
Impressum