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

NAME

6       CREATE FUNCTION - define a new function
7
8

SYNOPSIS

10       CREATE [ OR REPLACE ] FUNCTION
11           name ( [ [ argmode ] [ argname ] argtype [, ...] ] )
12           [ RETURNS rettype ]
13         { LANGUAGE langname
14           | IMMUTABLE | STABLE | VOLATILE
15           | CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
16           | [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
17           | AS 'definition'
18           | AS 'obj_file', 'link_symbol'
19         } ...
20           [ WITH ( attribute [, ...] ) ]
21
22

DESCRIPTION

24       CREATE  FUNCTION  defines  a  new function.  CREATE OR REPLACE FUNCTION
25       will either create a new function, or replace an existing definition.
26
27       If a schema name is included, then the function is created in the spec‐
28       ified  schema. Otherwise it is created in the current schema.  The name
29       of the new function must not match any existing function with the  same
30       argument  types  in  the  same  schema. However, functions of different
31       argument types may share a name (this is called overloading).
32
33       To update the definition of an existing function, use CREATE OR REPLACE
34       FUNCTION.  It is not possible to change the name or argument types of a
35       function this way (if you tried, you would actually be creating a  new,
36       distinct  function).  Also, CREATE OR REPLACE FUNCTION will not let you
37       change the return type of an existing function. To do  that,  you  must
38       drop  and recreate the function. (When using OUT parameters, that means
39       you can't change the names or types of any  OUT  parameters  except  by
40       dropping the function.)
41
42       If  you  drop and then recreate a function, the new function is not the
43       same entity as the old; you will have to drop  existing  rules,  views,
44       triggers,  etc.  that  refer to the old function. Use CREATE OR REPLACE
45       FUNCTION to change a function definition without breaking objects  that
46       refer to the function.
47
48       The user that creates the function becomes the owner of the function.
49

PARAMETERS

51       name   The  name  (optionally schema-qualified) of the function to cre‐
52              ate.
53
54       argmode
55              The mode of an argument: either IN, OUT, or INOUT.  If  omitted,
56              the default is IN.
57
58       argname
59              The   name  of  an  argument.  Some  languages  (currently  only
60              PL/pgSQL) let you use the name in the function body.  For  other
61              languages the name of an input argument is just extra documenta‐
62              tion. But the name of an output argument is  significant,  since
63              it  defines the column name in the result row type. (If you omit
64              the name for an  output  argument,  the  system  will  choose  a
65              default column name.)
66
67       argtype
68              The data type(s) of the function's arguments (optionally schema-
69              qualified), if any. The argument types may be  base,  composite,
70              or domain types, or may reference the type of a table column.
71
72              Depending  on the implementation language it may also be allowed
73              to specify ``pseudotypes'' such as cstring.   Pseudotypes  indi‐
74              cate that the actual argument type is either incompletely speci‐
75              fied, or outside the set of ordinary SQL data types.
76
77              The type of a column is referenced by writing  tablename.column‐
78              name%TYPE.   Using  this feature can sometimes help make a func‐
79              tion independent of changes to the definition of a table.
80
81       rettype
82              The return data type (optionally schema-qualified).  The  return
83              type  may be a base, composite, or domain type, or may reference
84              the type of a table column.   Depending  on  the  implementation
85              language  it may also be allowed to specify ``pseudotypes'' such
86              as cstring.  If the function is not supposed to return a  value,
87              specify void as the return type.
88
89              When  there  are OUT or INOUT parameters, the RETURNS clause may
90              be omitted. If present, it  must  agree  with  the  result  type
91              implied  by  the output parameters: RECORD if there are multiple
92              output parameters, or the same type as the single output parame‐
93              ter.
94
95              The SETOF modifier indicates that the function will return a set
96              of items, rather than a single item.
97
98              The type of a column is referenced by writing  tablename.column‐
99              name%TYPE.
100
101       langname
102              The  name  of  the language that the function is implemented in.
103              May be SQL, C, internal, or the name of a user-defined procedur‐
104              al  language.  For  backward  compatibility,  the  name  may  be
105              enclosed by single quotes.
106
107       IMMUTABLE
108
109       STABLE
110
111       VOLATILE
112              These attributes inform the query optimizer about  the  behavior
113              of the function. At most one choice may be specified. If none of
114              these appear, VOLATILE is the default assumption.
115
116              IMMUTABLE indicates that the function cannot modify the database
117              and  always returns the same result when given the same argument
118              values; that is, it does not do database  lookups  or  otherwise
119              use  information  not  directly present in its argument list. If
120              this option is given, any call of the function with all-constant
121              arguments can be immediately replaced with the function value.
122
123              STABLE  indicates  that the function cannot modify the database,
124              and that within a single table scan it will consistently  return
125              the  same  result  for  the  same  argument values, but that its
126              result could change across SQL statements. This is the appropri‐
127              ate  selection  for  functions  whose results depend on database
128              lookups, parameter variables (such as the  current  time  zone),
129              etc.  Also  note  that the current_timestamp family of functions
130              qualify as stable, since their values do  not  change  within  a
131              transaction.
132
133              VOLATILE  indicates  that  the  function  value  can change even
134              within a single table scan, so no  optimizations  can  be  made.
135              Relatively  few  database  functions are volatile in this sense;
136              some examples are random(),  currval(),  timeofday().  But  note
137              that  any  function  that  has  side-effects  must be classified
138              volatile, even if its result is quite  predictable,  to  prevent
139              calls from being optimized away; an example is setval().
140
141              For additional details see in the documentation.
142
143       CALLED ON NULL INPUT
144
145       RETURNS NULL ON NULL INPUT
146
147       STRICT CALLED  ON  NULL INPUT (the default) indicates that the function
148              will be called normally when some of its arguments are null.  It
149              is  then  the function author's responsibility to check for null
150              values if necessary and respond appropriately.
151
152              RETURNS NULL ON NULL INPUT or STRICT indicates that the function
153              always  returns  null whenever any of its arguments are null. If
154              this parameter is specified, the function is not  executed  when
155              there are null arguments; instead a null result is assumed auto‐
156              matically.
157
158       [EXTERNAL] SECURITY INVOKER
159
160       [EXTERNAL] SECURITY DEFINER
161              SECURITY INVOKER indicates that the function is to  be  executed
162              with  the  privileges  of  the  user that calls it.  That is the
163              default. SECURITY DEFINER specifies that the function is  to  be
164              executed with the privileges of the user that created it.
165
166              The  key word EXTERNAL is allowed for SQL conformance, but it is
167              optional since, unlike in SQL, this feature applies to all func‐
168              tions not only external ones.
169
170       definition
171              A  string constant defining the function; the meaning depends on
172              the language. It may be an internal function name, the  path  to
173              an  object  file,  an  SQL command, or text in a procedural lan‐
174              guage.
175
176       obj_file, link_symbol
177              This form of the AS clause is used for  dynamically  loadable  C
178              language  functions  when  the  function  name in the C language
179              source code is not the same as the name of the SQL function. The
180              string  obj_file  is the name of the file containing the dynami‐
181              cally loadable object, and link_symbol is  the  function's  link
182              symbol,  that  is,  the  name  of the function in the C language
183              source code. If the link symbol is omitted, it is assumed to  be
184              the same as the name of the SQL function being defined.
185
186       attribute
187              The  historical  way  to  specify optional pieces of information
188              about the function. The following attributes may appear here:
189
190              isStrict
191                     Equivalent to STRICT or RETURNS NULL ON NULL INPUT.
192
193              isCachable
194                     isCachable is an obsolete equivalent of  IMMUTABLE;  it's
195                     still accepted for backwards-compatibility reasons.
196
197       Attribute names are not case-sensitive.
198

NOTES

200       Refer  to in the documentation for further information on writing func‐
201       tions.
202
203       The full SQL type syntax is allowed  for  input  arguments  and  return
204       value.  However, some details of the type specification (e.g., the pre‐
205       cision field for type numeric) are the responsibility of the underlying
206       function  implementation  and  are silently swallowed (i.e., not recog‐
207       nized or enforced) by the CREATE FUNCTION command.
208
209       PostgreSQL allows function overloading; that is, the same name  can  be
210       used  for  several  different  functions  so long as they have distinct
211       argument types. However, the C names of all functions must  be  differ‐
212       ent,  so  you  must  give overloaded C functions different C names (for
213       example, use the argument types as part of the C names).
214
215       Two functions are considered the same if they have the same  names  and
216       input  argument  types,  ignoring  any OUT parameters. Thus for example
217       these declarations conflict:
218
219       CREATE FUNCTION foo(int) ...
220       CREATE FUNCTION foo(int, out text) ...
221
222
223       When repeated CREATE FUNCTION calls refer to the same object file,  the
224       file is only loaded once. To unload and reload the file (perhaps during
225       development), use the LOAD [load(7)] command.
226
227       Use DROP FUNCTION [drop_function(7)] to remove user-defined functions.
228
229       It is often helpful to use dollar quoting (see in the documentation) to
230       write  the  function  definition  string, rather than the normal single
231       quote syntax. Without dollar quoting, any single quotes or  backslashes
232       in the function definition must be escaped by doubling them.
233
234       To be able to define a function, the user must have the USAGE privilege
235       on the language.
236

EXAMPLES

238       Here are some trivial examples to help you get started. For more infor‐
239       mation and examples, see in the documentation.
240
241       CREATE FUNCTION add(integer, integer) RETURNS integer
242           AS 'select $1 + $2;'
243           LANGUAGE SQL
244           IMMUTABLE
245           RETURNS NULL ON NULL INPUT;
246
247
248       Increment an integer, making use of an argument name, in PL/pgSQL:
249
250       CREATE OR REPLACE FUNCTION increment(i integer) RETURNS integer AS $$
251               BEGIN
252                       RETURN i + 1;
253               END;
254       $$ LANGUAGE plpgsql;
255
256
257       Return a record containing multiple output parameters:
258
259       CREATE FUNCTION dup(in int, out f1 int, out f2 text)
260           AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
261           LANGUAGE SQL;
262
263       SELECT * FROM dup(42);
264
265       You  can do the same thing more verbosely with an explicitly named com‐
266       posite type:
267
268       CREATE TYPE dup_result AS (f1 int, f2 text);
269
270       CREATE FUNCTION dup(int) RETURNS dup_result
271           AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
272           LANGUAGE SQL;
273
274       SELECT * FROM dup(42);
275
276

WRITING SECURITY DEFINER FUNCTIONS SAFELY

278       Because a SECURITY DEFINER function is executed with the privileges  of
279       the  user  that  created it, care is needed to ensure that the function
280       cannot be misused. For security, search_path should be set  to  exclude
281       any  schemas writable by untrusted users. This prevents malicious users
282       from creating objects that mask objects used by the function.  Particu‐
283       larly  important in this regard is the temporary-table schema, which is
284       searched first by default, and is normally writable by anyone. A secure
285       arrangement  can  be had by forcing the temporary schema to be searched
286       last. To do this, write pg_temp as the last entry in search_path.  This
287       function illustrates safe usage:
288
289       CREATE FUNCTION check_password(uname TEXT, pass TEXT)
290       RETURNS BOOLEAN AS $$
291       DECLARE passed BOOLEAN;
292               old_path TEXT;
293       BEGIN
294               -- Save old search_path; notice we must qualify current_setting
295               -- to ensure we invoke the right function
296               old_path := pg_catalog.current_setting('search_path');
297
298               -- Set a secure search_path: trusted schemas, then 'pg_temp'.
299               -- We set is_local = true so that the old value will be restored
300               -- in event of an error before we reach the function end.
301               PERFORM pg_catalog.set_config('search_path', 'admin, pg_temp', true);
302
303               -- Do whatever secure work we came for.
304               SELECT  (pwd = $2) INTO passed
305               FROM    pwds
306               WHERE   username = $1;
307
308               -- Restore caller's search_path
309               PERFORM pg_catalog.set_config('search_path', old_path, true);
310
311               RETURN passed;
312       END;
313       $$ LANGUAGE plpgsql SECURITY DEFINER;
314
315

COMPATIBILITY

317       A  CREATE FUNCTION command is defined in SQL:1999 and later.  The Post‐
318       greSQL version is similar but not fully compatible. The attributes  are
319       not portable, neither are the different available languages.
320
321       For  compatibility  with  some  other  database systems, argmode can be
322       written either before or after argname.  But  only  the  first  way  is
323       standard-compliant.
324

SEE ALSO

326       ALTER  FUNCTION  [alter_function(7)], DROP FUNCTION [drop_function(l)],
327       GRANT [grant(l)], LOAD [load(l)], REVOKE [revoke(l)], createlang  [cre‐
328       atelang(1)]
329
330
331
332SQL - Language Statements         2008-06-08                 CREATE FUNCTION()
Impressum