1CREATE FUNCTION(7)               SQL Commands               CREATE FUNCTION(7)
2
3
4

NAME

6       CREATE FUNCTION - define a new function
7
8

SYNOPSIS

10       CREATE [ OR REPLACE ] FUNCTION
11           name ( [ [ argmode ] [ argname ] argtype [ { DEFAULT | = } defexpr ] [, ...] ] )
12           [ RETURNS rettype
13             | RETURNS TABLE ( colname coltype [, ...] ) ]
14         { LANGUAGE langname
15           | WINDOW
16           | IMMUTABLE | STABLE | VOLATILE
17           | CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
18           | [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
19           | COST execution_cost
20           | ROWS result_rows
21           | SET configuration_parameter { TO value | = value | FROM CURRENT }
22           | AS 'definition'
23           | AS 'obj_file', 'link_symbol'
24         } ...
25           [ WITH ( attribute [, ...] ) ]
26
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
32       If a schema name is included, then the function is created in the spec‐
33       ified  schema. Otherwise it is created in the current schema.  The name
34       of the new function must not match any existing function with the  same
35       input  argument types in the same schema. However, functions of differ‐
36       ent 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  cre‐
41       ating a new, distinct function).  Also, CREATE OR REPLACE FUNCTION will
42       not let you change the return type of an existing function. To do that,
43       you  must  drop  and recreate the function. (When using OUT parameters,
44       that means you cannot change the names or types of any  OUT  parameters
45       except by dropping the function.)
46
47       If  you  drop and then recreate a function, the new function is not the
48       same entity as the old; you will have to drop  existing  rules,  views,
49       triggers,  etc.  that  refer to the old function. Use CREATE OR REPLACE
50       FUNCTION to change a function definition without breaking objects  that
51       refer to the function.  Also, ALTER FUNCTION can be used to change most
52       of the auxiliary properties of an existing function.
53
54       The user that creates the function becomes the owner of the function.
55

PARAMETERS

57       name   The name (optionally schema-qualified) of the function  to  cre‐
58              ate.
59
60       argmode
61              The  mode of an argument: IN, OUT, INOUT, or VARIADIC.  If omit‐
62              ted, the default is IN.  Only OUT arguments can follow  a  VARI‐
63              ADIC one.  Also, OUT and INOUT arguments cannot be used together
64              with the RETURNS TABLE notation.
65
66       argname
67              The name of an argument. Some languages (including PL/pgSQL, but
68              currently  not  SQL)  let you use the name in the function body.
69              For other languages the name of an input argument is just  extra
70              documentation.  But  the  name of an output argument is signifi‐
71              cant, since it defines the column name in the result  row  type.
72              (If  you  omit  the name for an output argument, the system will
73              choose a default column name.)
74
75       argtype
76              The data type(s) of the function's arguments (optionally schema-
77              qualified),  if  any. The argument types can be base, composite,
78              or domain types, or can reference the type of a table column.
79
80              Depending on  the  implementation  language  it  might  also  be
81              allowed to specify ``pseudotypes'' such as cstring.  Pseudotypes
82              indicate that the actual argument type  is  either  incompletely
83              specified, or outside the set of ordinary SQL data types.
84
85              The  type of a column is referenced by writing tablename.column‐
86              name%TYPE.  Using this feature can sometimes help make  a  func‐
87              tion independent of changes to the definition of a table.
88
89       defexpr
90              An  expression  to  be used as default value if the parameter is
91              not specified. The expression has to be coercible to  the  argu‐
92              ment type of the parameter.  Only input (including INOUT) param‐
93              eters can have a default value. All input parameters following a
94              parameter with a default value must have default values as well.
95
96       rettype
97              The  return  data type (optionally schema-qualified). The return
98              type can be a base, composite, or domain type, or can  reference
99              the  type  of  a  table column.  Depending on the implementation
100              language it might also be  allowed  to  specify  ``pseudotypes''
101              such  as  cstring.   If the function is not supposed to return a
102              value, specify void as the return type.
103
104              When there are OUT or INOUT parameters, the RETURNS  clause  can
105              be  omitted.  If  present,  it  must  agree with the result type
106              implied by the output parameters: RECORD if there  are  multiple
107              output parameters, or the same type as the single output parame‐
108              ter.
109
110              The SETOF modifier indicates that the function will return a set
111              of items, rather than a single item.
112
113              The  type of a column is referenced by writing tablename.column‐
114              name%TYPE.
115
116       colname
117              The name of an output column in the RETURNS TABLE  syntax.  This
118              is  effectively  another way of declaring a named OUT parameter,
119              except that RETURNS TABLE also implies RETURNS SETOF.
120
121       coltype
122              The data type of an output column in the RETURNS TABLE syntax.
123
124       langname
125              The name of the language that the function  is  implemented  in.
126              Can be SQL, C, internal, or the name of a user-defined procedur‐
127              al  language.  For  backward  compatibility,  the  name  can  be
128              enclosed by single quotes.
129
130       WINDOW WINDOW  indicates  that the function is a window function rather
131              than a plain function.  This is currently only useful for  func‐
132              tions written in C.  The WINDOW attribute cannot be changed when
133              replacing an existing function definition.
134
135       IMMUTABLE
136
137       STABLE
138
139       VOLATILE
140              These attributes inform the query optimizer about  the  behavior
141              of the function. At most one choice can be specified. If none of
142              these appear, VOLATILE is the default assumption.
143
144              IMMUTABLE indicates that the function cannot modify the database
145              and  always returns the same result when given the same argument
146              values; that is, it does not do database  lookups  or  otherwise
147              use  information  not  directly present in its argument list. If
148              this option is given, any call of the function with all-constant
149              arguments can be immediately replaced with the function value.
150
151              STABLE  indicates  that the function cannot modify the database,
152              and that within a single table scan it will consistently  return
153              the  same  result  for  the  same  argument values, but that its
154              result could change across SQL statements. This is the appropri‐
155              ate  selection  for  functions  whose results depend on database
156              lookups, parameter variables (such as the  current  time  zone),
157              etc.  Also  note  that the current_timestamp family of functions
158              qualify as stable, since their values do  not  change  within  a
159              transaction.
160
161              VOLATILE  indicates  that  the  function  value  can change even
162              within a single table scan, so no  optimizations  can  be  made.
163              Relatively  few  database  functions are volatile in this sense;
164              some examples are random(),  currval(),  timeofday().  But  note
165              that  any  function  that  has  side-effects  must be classified
166              volatile, even if its result is quite  predictable,  to  prevent
167              calls from being optimized away; an example is setval().
168
169              For additional details see in the documentation.
170
171       CALLED ON NULL INPUT
172
173       RETURNS NULL ON NULL INPUT
174
175       STRICT CALLED  ON  NULL INPUT (the default) indicates that the function
176              will be called normally when some of its arguments are null.  It
177              is  then  the function author's responsibility to check for null
178              values if necessary and respond appropriately.
179
180              RETURNS NULL ON NULL INPUT or STRICT indicates that the function
181              always  returns  null whenever any of its arguments are null. If
182              this parameter is specified, the function is not  executed  when
183              there are null arguments; instead a null result is assumed auto‐
184              matically.
185
186       [EXTERNAL] SECURITY INVOKER
187
188       [EXTERNAL] SECURITY DEFINER
189              SECURITY INVOKER indicates that the function is to  be  executed
190              with  the  privileges  of  the  user that calls it.  That is the
191              default. SECURITY DEFINER specifies that the function is  to  be
192              executed with the privileges of the user that created it.
193
194              The  key word EXTERNAL is allowed for SQL conformance, but it is
195              optional since, unlike in SQL, this feature applies to all func‐
196              tions not only external ones.
197
198       execution_cost
199              A  positive  number  giving the estimated execution cost for the
200              function, in units of cpu_operator_cost. If the function returns
201              a  set,  this  is  the cost per returned row. If the cost is not
202              specified, 1 unit is assumed for C-language and  internal  func‐
203              tions,  and  100  units  for  functions  in all other languages.
204              Larger values cause the planner to try to avoid  evaluating  the
205              function more often than necessary.
206
207       result_rows
208              A  positive  number giving the estimated number of rows that the
209              planner should expect the  function  to  return.  This  is  only
210              allowed  when  the  function  is  declared  to return a set. The
211              default assumption is 1000 rows.
212
213       configuration_parameter
214
215       value  The SET clause causes the specified configuration  parameter  to
216              be  set to the specified value when the function is entered, and
217              then restored to its prior value when the function  exits.   SET
218              FROM  CURRENT saves the session's current value of the parameter
219              as the value to be applied when the function is entered.
220
221              See SET [set(7)] and in the documentation for  more  information
222              about allowed parameter names and values.
223
224       definition
225              A  string constant defining the function; the meaning depends on
226              the language. It can be an internal function name, the  path  to
227              an  object  file,  an  SQL command, or text in a procedural lan‐
228              guage.
229
230       obj_file, link_symbol
231              This form of the AS clause is used for  dynamically  loadable  C
232              language  functions  when  the  function  name in the C language
233              source code is not the same as the name of the SQL function. The
234              string  obj_file  is the name of the file containing the dynami‐
235              cally loadable object, and link_symbol is  the  function's  link
236              symbol,  that  is,  the  name  of the function in the C language
237              source code. If the link symbol is omitted, it is assumed to  be
238              the same as the name of the SQL function being defined.
239
240       attribute
241              The  historical  way  to  specify optional pieces of information
242              about the function. The following attributes can appear here:
243
244              isStrict
245                     Equivalent to STRICT or RETURNS NULL ON NULL INPUT.
246
247              isCachable
248                     isCachable is an obsolete equivalent of  IMMUTABLE;  it's
249                     still accepted for backwards-compatibility reasons.
250
251       Attribute names are not case-sensitive.
252

NOTES

254       Refer  to in the documentation for further information on writing func‐
255       tions.
256
257       The full SQL type syntax is allowed for declaring  a  function's  argu‐
258       ments  and  return  value. However, parenthesized type modifiers (e.g.,
259       the precision field for type numeric) are discarded by CREATE FUNCTION.
260       Thus  for example CREATE FUNCTION foo (varchar(10)) ...  is exactly the
261       same as CREATE FUNCTION foo (varchar) ....
262
263       PostgreSQL allows function overloading; that is, the same name  can  be
264       used  for  several  different  functions  so long as they have distinct
265       input argument types. However, the C names of  all  functions  must  be
266       different,  so  you  must give overloaded C functions different C names
267       (for example, use the argument types as part of the C names).
268
269       Two functions are considered the same if they have the same  names  and
270       input  argument  types,  ignoring  any OUT parameters. Thus for example
271       these declarations conflict:
272
273       CREATE FUNCTION foo(int) ...
274       CREATE FUNCTION foo(int, out text) ...
275
276
277       Functions that have different argument type lists will not  be  consid‐
278       ered  to  conflict  at creation time, but if defaults are provided they
279       might conflict in use. For example, consider
280
281       CREATE FUNCTION foo(int) ...
282       CREATE FUNCTION foo(int, int default 42) ...
283
284       A call foo(10) will fail due to  the  ambiguity  about  which  function
285       should be called.
286
287       When  repeated CREATE FUNCTION calls refer to the same object file, the
288       file is only loaded once per session.  To unload and  reload  the  file
289       (perhaps during development), start a new session.
290
291       Use DROP FUNCTION [drop_function(7)] to remove user-defined functions.
292
293       It is often helpful to use dollar quoting (see in the documentation) to
294       write the function definition string, rather  than  the  normal  single
295       quote  syntax. Without dollar quoting, any single quotes or backslashes
296       in the function definition must be escaped by doubling them.
297
298       If a SET clause is attached to a function, then the effects  of  a  SET
299       LOCAL  command  executed  inside the function for the same variable are
300       restricted to the function: the configuration parameter's  prior  value
301       is  still  restored at function exit.  However, an ordinary SET command
302       (without LOCAL) overrides the SET clause, much as it  would  do  for  a
303       previous  SET LOCAL command: the effects of such a command will persist
304       after function exit, unless the current transaction is rolled back.
305
306       To be able to define a function, the user must have the USAGE privilege
307       on the language.
308
309       When  CREATE  OR  REPLACE FUNCTION is used to replace an existing func‐
310       tion, the ownership and permissions of the function do not change.  All
311       other  function properties are assigned the values specified or implied
312       in the command. You must own the function to replace it (this  includes
313       being a member of the owning role).
314
315       If  a function is declared STRICT with a VARIADIC argument, the strict‐
316       ness check tests that the variadic array as a whole  is  non-null.  The
317       function will still be called if the array has null elements.
318

EXAMPLES

320       Here are some trivial examples to help you get started. For more infor‐
321       mation and examples, see in the documentation.
322
323       CREATE FUNCTION add(integer, integer) RETURNS integer
324           AS 'select $1 + $2;'
325           LANGUAGE SQL
326           IMMUTABLE
327           RETURNS NULL ON NULL INPUT;
328
329
330       Increment an integer, making use of an argument name, in PL/pgSQL:
331
332       CREATE OR REPLACE FUNCTION increment(i integer) RETURNS integer AS $$
333               BEGIN
334                       RETURN i + 1;
335               END;
336       $$ LANGUAGE plpgsql;
337
338
339       Return a record containing multiple output parameters:
340
341       CREATE FUNCTION dup(in int, out f1 int, out f2 text)
342           AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
343           LANGUAGE SQL;
344
345       SELECT * FROM dup(42);
346
347       You can do the same thing more verbosely with an explicitly named  com‐
348       posite type:
349
350       CREATE TYPE dup_result AS (f1 int, f2 text);
351
352       CREATE FUNCTION dup(int) RETURNS dup_result
353           AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
354           LANGUAGE SQL;
355
356       SELECT * FROM dup(42);
357
358       Another way to return multiple columns is to use a TABLE function:
359
360       CREATE FUNCTION dup(int) RETURNS TABLE(f1 int, f2 text)
361           AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
362           LANGUAGE SQL;
363
364       SELECT * FROM dup(42);
365
366       However,  a  TABLE  function  is different from the preceding examples,
367       because it actually returns a set of records, not just one record.
368

WRITING SECURITY DEFINER FUNCTIONS SAFELY

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

COMPATIBILITY

419       A  CREATE FUNCTION command is defined in SQL:1999 and later.  The Post‐
420       greSQL version is similar but not fully compatible. The attributes  are
421       not portable, neither are the different available languages.
422
423       For  compatibility  with  some  other  database systems, argmode can be
424       written either before or after argname.  But  only  the  first  way  is
425       standard-compliant.
426
427       The  SQL  standard does not specify parameter defaults. The syntax with
428       the DEFAULT key word is from Oracle, and it is somewhat in  the  spirit
429       of  the standard: SQL/PSM uses it for variable default values. The syn‐
430       tax with = is used in T-SQL and Firebird.
431

SEE ALSO

433       ALTER FUNCTION [alter_function(7)], DROP  FUNCTION  [drop_function(7)],
434       GRANT  [grant(7)], LOAD [load(7)], REVOKE [revoke(7)], createlang [cre‐
435       atelang(1)]
436
437
438
439SQL - Language Statements         2014-02-17                CREATE FUNCTION(7)
Impressum