1<!--
2doc/src/sgml/ref/create_function.sgml
3PostgreSQL documentation
4-->
5
6<refentry id="sql-createfunction">
7 <indexterm zone="sql-createfunction">
8  <primary>CREATE FUNCTION</primary>
9 </indexterm>
10
11 <refmeta>
12  <refentrytitle>CREATE FUNCTION</refentrytitle>
13  <manvolnum>7</manvolnum>
14  <refmiscinfo>SQL - Language Statements</refmiscinfo>
15 </refmeta>
16
17 <refnamediv>
18  <refname>CREATE FUNCTION</refname>
19  <refpurpose>define a new function</refpurpose>
20 </refnamediv>
21
22 <refsynopsisdiv>
23<synopsis>
24CREATE [ OR REPLACE ] FUNCTION
25    <replaceable class="parameter">name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [ { DEFAULT | = } <replaceable class="parameter">default_expr</replaceable> ] [, ...] ] )
26    [ RETURNS <replaceable class="parameter">rettype</replaceable>
27      | RETURNS TABLE ( <replaceable class="parameter">column_name</replaceable> <replaceable class="parameter">column_type</replaceable> [, ...] ) ]
28  { LANGUAGE <replaceable class="parameter">lang_name</replaceable>
29    | TRANSFORM { FOR TYPE <replaceable class="parameter">type_name</replaceable> } [, ... ]
30    | WINDOW
31    | { IMMUTABLE | STABLE | VOLATILE }
32    | [ NOT ] LEAKPROOF
33    | { CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT }
34    | { [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER }
35    | PARALLEL { UNSAFE | RESTRICTED | SAFE }
36    | COST <replaceable class="parameter">execution_cost</replaceable>
37    | ROWS <replaceable class="parameter">result_rows</replaceable>
38    | SUPPORT <replaceable class="parameter">support_function</replaceable>
39    | SET <replaceable class="parameter">configuration_parameter</replaceable> { TO <replaceable class="parameter">value</replaceable> | = <replaceable class="parameter">value</replaceable> | FROM CURRENT }
40    | AS '<replaceable class="parameter">definition</replaceable>'
41    | AS '<replaceable class="parameter">obj_file</replaceable>', '<replaceable class="parameter">link_symbol</replaceable>'
42  } ...
43</synopsis>
44 </refsynopsisdiv>
45
46 <refsect1 id="sql-createfunction-description">
47  <title>Description</title>
48
49  <para>
50   <command>CREATE FUNCTION</command> defines a new function.
51   <command>CREATE OR REPLACE FUNCTION</command> will either create a
52   new function, or replace an existing definition.
53   To be able to define a function, the user must have the
54   <literal>USAGE</literal> privilege on the language.
55  </para>
56
57  <para>
58   If a schema name is included, then the function is created in the
59   specified schema.  Otherwise it is created in the current schema.
60   The name of the new function must not match any existing function or procedure
61   with the same input argument types in the same schema.  However,
62   functions and procedures of different argument types can share a name (this is
63   called <firstterm>overloading</firstterm>).
64  </para>
65
66  <para>
67   To replace the current definition of an existing function, use
68   <command>CREATE OR REPLACE FUNCTION</command>.  It is not possible
69   to change the name or argument types of a function this way (if you
70   tried, you would actually be creating a new, distinct function).
71   Also, <command>CREATE OR REPLACE FUNCTION</command> will not let
72   you change the return type of an existing function.  To do that,
73   you must drop and recreate the function.  (When using <literal>OUT</literal>
74   parameters, that means you cannot change the types of any
75   <literal>OUT</literal> parameters except by dropping the function.)
76  </para>
77
78  <para>
79   When <command>CREATE OR REPLACE FUNCTION</command> is used to replace an
80   existing function, the ownership and permissions of the function
81   do not change.  All other function properties are assigned the
82   values specified or implied in the command.  You must own the function
83   to replace it (this includes being a member of the owning role).
84  </para>
85
86  <para>
87   If you drop and then recreate a function, the new function is not
88   the same entity as the old; you will have to drop existing rules, views,
89   triggers, etc. that refer to the old function.  Use
90   <command>CREATE OR REPLACE FUNCTION</command> to change a function
91   definition without breaking objects that refer to the function.
92   Also, <command>ALTER FUNCTION</command> can be used to change most of the
93   auxiliary properties of an existing function.
94  </para>
95
96  <para>
97   The user that creates the function becomes the owner of the function.
98  </para>
99
100  <para>
101   To be able to create a function, you must have <literal>USAGE</literal>
102   privilege on the argument types and the return type.
103  </para>
104
105  <para>
106   Refer to <xref linkend="xfunc"/> for further information on writing
107   functions.
108  </para>
109 </refsect1>
110
111 <refsect1>
112  <title>Parameters</title>
113
114   <variablelist>
115
116    <varlistentry>
117     <term><replaceable class="parameter">name</replaceable></term>
118
119     <listitem>
120      <para>
121       The name (optionally schema-qualified) of the function to create.
122      </para>
123     </listitem>
124    </varlistentry>
125
126    <varlistentry>
127     <term><replaceable class="parameter">argmode</replaceable></term>
128
129     <listitem>
130      <para>
131       The mode of an argument: <literal>IN</literal>, <literal>OUT</literal>,
132       <literal>INOUT</literal>, or <literal>VARIADIC</literal>.
133       If omitted, the default is <literal>IN</literal>.
134       Only <literal>OUT</literal> arguments can follow a <literal>VARIADIC</literal> one.
135       Also, <literal>OUT</literal> and <literal>INOUT</literal> arguments cannot be used
136       together with the <literal>RETURNS TABLE</literal> notation.
137      </para>
138     </listitem>
139    </varlistentry>
140
141    <varlistentry>
142     <term><replaceable class="parameter">argname</replaceable></term>
143
144     <listitem>
145      <para>
146       The name of an argument. Some languages (including SQL and PL/pgSQL)
147       let you use the name in the function body.  For other languages the
148       name of an input argument is just extra documentation, so far as
149       the function itself is concerned; but you can use input argument names
150       when calling a function to improve readability (see <xref
151       linkend="sql-syntax-calling-funcs"/>).  In any case, the name
152       of an output argument is significant, because it defines the column
153       name in the result row type.  (If you omit the name for an output
154       argument, the system will choose a default column name.)
155      </para>
156     </listitem>
157    </varlistentry>
158
159    <varlistentry>
160     <term><replaceable class="parameter">argtype</replaceable></term>
161
162     <listitem>
163      <para>
164       The data type(s) of the function's arguments (optionally
165       schema-qualified), if any. The argument types can be base, composite,
166       or domain types, or can reference the type of a table column.
167      </para>
168      <para>
169       Depending on the implementation language it might also be allowed
170       to specify <quote>pseudo-types</quote> such as <type>cstring</type>.
171       Pseudo-types indicate that the actual argument type is either
172       incompletely specified, or outside the set of ordinary SQL data types.
173      </para>
174      <para>
175       The type of a column is referenced by writing
176       <literal><replaceable
177       class="parameter">table_name</replaceable>.<replaceable
178       class="parameter">column_name</replaceable>%TYPE</literal>.
179       Using this feature can sometimes help make a function independent of
180       changes to the definition of a table.
181      </para>
182     </listitem>
183    </varlistentry>
184
185    <varlistentry>
186     <term><replaceable class="parameter">default_expr</replaceable></term>
187
188     <listitem>
189      <para>
190       An expression to be used as default value if the parameter is
191       not specified.  The expression has to be coercible to the
192       argument type of the parameter.
193       Only input (including <literal>INOUT</literal>) parameters can have a default
194        value.  All input parameters following a
195       parameter with a default value must have default values as well.
196      </para>
197     </listitem>
198    </varlistentry>
199
200    <varlistentry>
201     <term><replaceable class="parameter">rettype</replaceable></term>
202
203     <listitem>
204      <para>
205       The return data type (optionally schema-qualified). The return type
206       can be a base, composite, or domain type,
207       or can reference the type of a table column.
208       Depending on the implementation language it might also be allowed
209       to specify <quote>pseudo-types</quote> such as <type>cstring</type>.
210       If the function is not supposed to return a value, specify
211       <type>void</type> as the return type.
212      </para>
213      <para>
214       When there are <literal>OUT</literal> or <literal>INOUT</literal> parameters,
215       the <literal>RETURNS</literal> clause can be omitted.  If present, it
216       must agree with the result type implied by the output parameters:
217       <literal>RECORD</literal> if there are multiple output parameters, or
218       the same type as the single output parameter.
219      </para>
220      <para>
221       The <literal>SETOF</literal>
222       modifier indicates that the function will return a set of
223       items, rather than a single item.
224      </para>
225      <para>
226       The type of a column is referenced by writing
227       <literal><replaceable
228       class="parameter">table_name</replaceable>.<replaceable
229       class="parameter">column_name</replaceable>%TYPE</literal>.
230      </para>
231     </listitem>
232    </varlistentry>
233
234    <varlistentry>
235     <term><replaceable class="parameter">column_name</replaceable></term>
236
237     <listitem>
238      <para>
239       The name of an output column in the <literal>RETURNS TABLE</literal>
240       syntax.  This is effectively another way of declaring a named
241       <literal>OUT</literal> parameter, except that <literal>RETURNS TABLE</literal>
242       also implies <literal>RETURNS SETOF</literal>.
243      </para>
244     </listitem>
245    </varlistentry>
246
247    <varlistentry>
248     <term><replaceable class="parameter">column_type</replaceable></term>
249
250     <listitem>
251      <para>
252       The data type of an output column in the <literal>RETURNS TABLE</literal>
253       syntax.
254      </para>
255     </listitem>
256    </varlistentry>
257
258    <varlistentry>
259     <term><replaceable class="parameter">lang_name</replaceable></term>
260
261     <listitem>
262      <para>
263       The name of the language that the function is implemented in.
264       It can be <literal>sql</literal>, <literal>c</literal>,
265       <literal>internal</literal>, or the name of a user-defined
266       procedural language, e.g., <literal>plpgsql</literal>.  Enclosing the
267       name in single quotes is deprecated and requires matching case.
268      </para>
269     </listitem>
270    </varlistentry>
271
272    <varlistentry>
273     <term><literal>TRANSFORM { FOR TYPE <replaceable class="parameter">type_name</replaceable> } [, ... ] }</literal></term>
274
275     <listitem>
276      <para>
277       Lists which transforms a call to the function should apply.  Transforms
278       convert between SQL types and language-specific data types;
279       see <xref linkend="sql-createtransform"/>.  Procedural language
280       implementations usually have hardcoded knowledge of the built-in types,
281       so those don't need to be listed here.  If a procedural language
282       implementation does not know how to handle a type and no transform is
283       supplied, it will fall back to a default behavior for converting data
284       types, but this depends on the implementation.
285      </para>
286     </listitem>
287    </varlistentry>
288
289    <varlistentry>
290     <term><literal>WINDOW</literal></term>
291
292     <listitem>
293      <para><literal>WINDOW</literal> indicates that the function is a
294       <firstterm>window function</firstterm> rather than a plain function.
295       This is currently only useful for functions written in C.
296       The <literal>WINDOW</literal> attribute cannot be changed when
297       replacing an existing function definition.
298      </para>
299     </listitem>
300    </varlistentry>
301
302    <varlistentry>
303     <term><literal>IMMUTABLE</literal></term>
304     <term><literal>STABLE</literal></term>
305     <term><literal>VOLATILE</literal></term>
306
307     <listitem>
308      <para>
309       These attributes inform the query optimizer about the behavior
310       of the function.  At most one choice
311       can be specified.  If none of these appear,
312       <literal>VOLATILE</literal> is the default assumption.
313      </para>
314
315      <para><literal>IMMUTABLE</literal> indicates that the function
316       cannot modify the database and always
317       returns the same result when given the same argument values; that
318       is, it does not do database lookups or otherwise use information not
319       directly present in its argument list.  If this option is given,
320       any call of the function with all-constant arguments can be
321       immediately replaced with the function value.
322      </para>
323
324      <para><literal>STABLE</literal> indicates that the function
325       cannot modify the database,
326       and that within a single table scan it will consistently
327       return the same result for the same argument values, but that its
328       result could change across SQL statements.  This is the appropriate
329       selection for functions whose results depend on database lookups,
330       parameter variables (such as the current time zone), etc.  (It is
331       inappropriate for <literal>AFTER</literal> triggers that wish to
332       query rows modified by the current command.)  Also note
333       that the <function>current_timestamp</function> family of functions qualify
334       as stable, since their values do not change within a transaction.
335      </para>
336
337      <para><literal>VOLATILE</literal> indicates that the function value can
338       change even within a single table scan, so no optimizations can be
339       made.  Relatively few database functions are volatile in this sense;
340       some examples are <literal>random()</literal>, <literal>currval()</literal>,
341       <literal>timeofday()</literal>.  But note that any function that has
342       side-effects must be classified volatile, even if its result is quite
343       predictable, to prevent calls from being optimized away; an example is
344       <literal>setval()</literal>.
345      </para>
346
347      <para>
348       For additional details see <xref linkend="xfunc-volatility"/>.
349      </para>
350     </listitem>
351    </varlistentry>
352
353    <varlistentry>
354     <term><literal>LEAKPROOF</literal></term>
355     <listitem>
356      <para>
357       <literal>LEAKPROOF</literal> indicates that the function has no side
358       effects.  It reveals no information about its arguments other than by
359       its return value.  For example, a function which throws an error message
360       for some argument values but not others, or which includes the argument
361       values in any error message, is not leakproof.  This affects how the
362       system executes queries against views created with the
363       <literal>security_barrier</literal> option or tables with row level
364       security enabled.  The system will enforce conditions from security
365       policies and security barrier views before any user-supplied conditions
366       from the query itself that contain non-leakproof functions, in order to
367       prevent the inadvertent exposure of data.  Functions and operators
368       marked as leakproof are assumed to be trustworthy, and may be executed
369       before conditions from security policies and security barrier views.
370       In addition, functions which do not take arguments or which are not
371       passed any arguments from the security barrier view or table do not have
372       to be marked as leakproof to be executed before security conditions.  See
373       <xref linkend="sql-createview"/> and <xref linkend="rules-privileges"/>.
374       This option can only be set by the superuser.
375      </para>
376     </listitem>
377    </varlistentry>
378
379    <varlistentry>
380     <term><literal>CALLED ON NULL INPUT</literal></term>
381     <term><literal>RETURNS NULL ON NULL INPUT</literal></term>
382     <term><literal>STRICT</literal></term>
383
384     <listitem>
385      <para><literal>CALLED ON NULL INPUT</literal> (the default) indicates
386       that the function will be called normally when some of its
387       arguments are null.  It is then the function author's
388       responsibility to check for null values if necessary and respond
389       appropriately.
390      </para>
391
392      <para><literal>RETURNS NULL ON NULL INPUT</literal> or
393       <literal>STRICT</literal> indicates that the function always
394       returns null whenever any of its arguments are null.  If this
395       parameter is specified, the function is not executed when there
396       are null arguments; instead a null result is assumed
397       automatically.
398      </para>
399     </listitem>
400    </varlistentry>
401
402   <varlistentry>
403    <term><literal><optional>EXTERNAL</optional> SECURITY INVOKER</literal></term>
404    <term><literal><optional>EXTERNAL</optional> SECURITY DEFINER</literal></term>
405
406    <listitem>
407     <para><literal>SECURITY INVOKER</literal> indicates that the function
408      is to be executed with the privileges of the user that calls it.
409      That is the default.  <literal>SECURITY DEFINER</literal>
410      specifies that the function is to be executed with the
411      privileges of the user that owns it.
412     </para>
413
414     <para>
415      The key word <literal>EXTERNAL</literal> is allowed for SQL
416      conformance, but it is optional since, unlike in SQL, this feature
417      applies to all functions not only external ones.
418     </para>
419    </listitem>
420   </varlistentry>
421
422   <varlistentry>
423    <term><literal>PARALLEL</literal></term>
424
425    <listitem>
426     <para><literal>PARALLEL UNSAFE</literal> indicates that the function
427      can't be executed in parallel mode and the presence of such a
428      function in an SQL statement forces a serial execution plan.  This is
429      the default.  <literal>PARALLEL RESTRICTED</literal> indicates that
430      the function can be executed in parallel mode, but the execution is
431      restricted to parallel group leader.  <literal>PARALLEL SAFE</literal>
432      indicates that the function is safe to run in parallel mode without
433      restriction.
434     </para>
435
436     <para>
437      Functions should be labeled parallel unsafe if they modify any database
438      state, or if they make changes to the transaction such as using
439      sub-transactions, or if they access sequences or attempt to make
440      persistent changes to settings (e.g., <literal>setval</literal>).  They should
441      be labeled as parallel restricted if they access temporary tables,
442      client connection state, cursors, prepared statements, or miscellaneous
443      backend-local state which the system cannot synchronize in parallel mode
444      (e.g.,  <literal>setseed</literal> cannot be executed other than by the group
445      leader because a change made by another process would not be reflected
446      in the leader).  In general, if a function is labeled as being safe when
447      it is restricted or unsafe, or if it is labeled as being restricted when
448      it is in fact unsafe, it may throw errors or produce wrong answers
449      when used in a parallel query.  C-language functions could in theory
450      exhibit totally undefined behavior if mislabeled, since there is no way
451      for the system to protect itself against arbitrary C code, but in most
452      likely cases the result will be no worse than for any other function.
453      If in doubt, functions should be labeled as <literal>UNSAFE</literal>, which is
454      the default.
455     </para>
456    </listitem>
457   </varlistentry>
458
459    <varlistentry>
460     <term><literal>COST</literal> <replaceable class="parameter">execution_cost</replaceable></term>
461
462     <listitem>
463      <para>
464       A positive number giving the estimated execution cost for the function,
465       in units of <xref linkend="guc-cpu-operator-cost"/>.  If the function
466       returns a set, this is the cost per returned row.  If the cost is
467       not specified, 1 unit is assumed for C-language and internal functions,
468       and 100 units for functions in all other languages.  Larger values
469       cause the planner to try to avoid evaluating the function more often
470       than necessary.
471      </para>
472     </listitem>
473    </varlistentry>
474
475    <varlistentry>
476     <term><literal>ROWS</literal> <replaceable class="parameter">result_rows</replaceable></term>
477
478     <listitem>
479      <para>
480       A positive number giving the estimated number of rows that the planner
481       should expect the function to return.  This is only allowed when the
482       function is declared to return a set.  The default assumption is
483       1000 rows.
484      </para>
485     </listitem>
486    </varlistentry>
487
488    <varlistentry>
489     <term><literal>SUPPORT</literal> <replaceable class="parameter">support_function</replaceable></term>
490
491     <listitem>
492      <para>
493       The name (optionally schema-qualified) of a <firstterm>planner support
494       function</firstterm> to use for this function.  See
495       <xref linkend="xfunc-optimization"/> for details.
496       You must be superuser to use this option.
497      </para>
498     </listitem>
499    </varlistentry>
500
501    <varlistentry>
502     <term><replaceable>configuration_parameter</replaceable></term>
503     <term><replaceable>value</replaceable></term>
504     <listitem>
505      <para>
506       The <literal>SET</literal> clause causes the specified configuration
507       parameter to be set to the specified value when the function is
508       entered, and then restored to its prior value when the function exits.
509       <literal>SET FROM CURRENT</literal> saves the value of the parameter that
510       is current when <command>CREATE FUNCTION</command> is executed as the value
511       to be applied when the function is entered.
512      </para>
513
514      <para>
515       If a <literal>SET</literal> clause is attached to a function, then
516       the effects of a <command>SET LOCAL</command> command executed inside the
517       function for the same variable are restricted to the function: the
518       configuration parameter's prior value is still restored at function exit.
519       However, an ordinary
520       <command>SET</command> command (without <literal>LOCAL</literal>) overrides the
521       <literal>SET</literal> clause, much as it would do for a previous <command>SET
522       LOCAL</command> command: the effects of such a command will persist after
523       function exit, unless the current transaction is rolled back.
524      </para>
525
526      <para>
527       See <xref linkend="sql-set"/> and
528       <xref linkend="runtime-config"/>
529       for more information about allowed parameter names and values.
530      </para>
531     </listitem>
532    </varlistentry>
533
534    <varlistentry>
535     <term><replaceable class="parameter">definition</replaceable></term>
536
537     <listitem>
538      <para>
539       A string constant defining the function; the meaning depends on the
540       language.  It can be an internal function name, the path to an
541       object file, an SQL command, or text in a procedural language.
542      </para>
543
544      <para>
545       It is often helpful to use dollar quoting (see <xref
546       linkend="sql-syntax-dollar-quoting"/>) to write the function definition
547       string, rather than the normal single quote syntax.  Without dollar
548       quoting, any single quotes or backslashes in the function definition must
549       be escaped by doubling them.
550      </para>
551
552     </listitem>
553    </varlistentry>
554
555    <varlistentry>
556     <term><literal><replaceable class="parameter">obj_file</replaceable>, <replaceable class="parameter">link_symbol</replaceable></literal></term>
557
558     <listitem>
559      <para>
560       This form of the <literal>AS</literal> clause is used for
561       dynamically loadable C language functions when the function name
562       in the C language source code is not the same as the name of
563       the SQL function. The string <replaceable
564       class="parameter">obj_file</replaceable> is the name of the shared
565       library file containing the compiled C function, and is interpreted
566       as for the <xref linkend="sql-load"/> command.  The string
567       <replaceable class="parameter">link_symbol</replaceable> is the
568       function's link symbol, that is, the name of the function in the C
569       language source code.  If the link symbol is omitted, it is assumed to
570       be the same as the name of the SQL function being defined.  The C names
571       of all functions must be different, so you must give overloaded C
572       functions different C names (for example, use the argument types as
573       part of the C names).
574      </para>
575
576      <para>
577       When repeated <command>CREATE FUNCTION</command> calls refer to
578       the same object file, the file is only loaded once per session.
579       To unload and
580       reload the file (perhaps during development), start a new session.
581      </para>
582
583     </listitem>
584    </varlistentry>
585
586   </variablelist>
587 </refsect1>
588
589 <refsect1 id="sql-createfunction-overloading">
590  <title>Overloading</title>
591
592   <para>
593    <productname>PostgreSQL</productname> allows function
594    <firstterm>overloading</firstterm>; that is, the same name can be
595    used for several different functions so long as they have distinct
596    input argument types.  Whether or not you use it, this capability entails
597    security precautions when calling functions in databases where some users
598    mistrust other users; see <xref linkend="typeconv-func"/>.
599   </para>
600
601   <para>
602    Two functions are considered the same if they have the same names and
603    <emphasis>input</emphasis> argument types, ignoring any <literal>OUT</literal>
604    parameters.  Thus for example these declarations conflict:
605<programlisting>
606CREATE FUNCTION foo(int) ...
607CREATE FUNCTION foo(int, out text) ...
608</programlisting>
609   </para>
610
611   <para>
612    Functions that have different argument type lists will not be considered
613    to conflict at creation time, but if defaults are provided they might
614    conflict in use.  For example, consider
615<programlisting>
616CREATE FUNCTION foo(int) ...
617CREATE FUNCTION foo(int, int default 42) ...
618</programlisting>
619    A call <literal>foo(10)</literal> will fail due to the ambiguity about which
620    function should be called.
621   </para>
622
623 </refsect1>
624
625 <refsect1 id="sql-createfunction-notes">
626  <title>Notes</title>
627
628   <para>
629    The full <acronym>SQL</acronym> type syntax is allowed for
630    declaring a function's arguments and return value.  However,
631    parenthesized type modifiers (e.g., the precision field for
632    type <type>numeric</type>) are discarded by <command>CREATE FUNCTION</command>.
633    Thus for example
634    <literal>CREATE FUNCTION foo (varchar(10)) ...</literal>
635    is exactly the same as
636    <literal>CREATE FUNCTION foo (varchar) ...</literal>.
637   </para>
638
639   <para>
640    When replacing an existing function with <command>CREATE OR REPLACE
641    FUNCTION</command>, there are restrictions on changing parameter names.
642    You cannot change the name already assigned to any input parameter
643    (although you can add names to parameters that had none before).
644    If there is more than one output parameter, you cannot change the
645    names of the output parameters, because that would change the
646    column names of the anonymous composite type that describes the
647    function's result.  These restrictions are made to ensure that
648    existing calls of the function do not stop working when it is replaced.
649   </para>
650
651   <para>
652    If a function is declared <literal>STRICT</literal> with a <literal>VARIADIC</literal>
653    argument, the strictness check tests that the variadic array <emphasis>as
654    a whole</emphasis> is non-null.  The function will still be called if the
655    array has null elements.
656   </para>
657
658 </refsect1>
659
660 <refsect1 id="sql-createfunction-examples">
661  <title>Examples</title>
662
663  <para>
664   Add two integers using a SQL function:
665<programlisting>
666CREATE FUNCTION add(integer, integer) RETURNS integer
667    AS 'select $1 + $2;'
668    LANGUAGE SQL
669    IMMUTABLE
670    RETURNS NULL ON NULL INPUT;
671</programlisting>
672  </para>
673
674  <para>
675   Increment an integer, making use of an argument name, in
676   <application>PL/pgSQL</application>:
677<programlisting>
678CREATE OR REPLACE FUNCTION increment(i integer) RETURNS integer AS $$
679        BEGIN
680                RETURN i + 1;
681        END;
682$$ LANGUAGE plpgsql;
683</programlisting>
684  </para>
685
686  <para>
687   Return a record containing multiple output parameters:
688<programlisting>
689CREATE FUNCTION dup(in int, out f1 int, out f2 text)
690    AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
691    LANGUAGE SQL;
692
693SELECT * FROM dup(42);
694</programlisting>
695   You can do the same thing more verbosely with an explicitly named
696   composite type:
697<programlisting>
698CREATE TYPE dup_result AS (f1 int, f2 text);
699
700CREATE FUNCTION dup(int) RETURNS dup_result
701    AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
702    LANGUAGE SQL;
703
704SELECT * FROM dup(42);
705</programlisting>
706   Another way to return multiple columns is to use a <literal>TABLE</literal>
707   function:
708<programlisting>
709CREATE FUNCTION dup(int) RETURNS TABLE(f1 int, f2 text)
710    AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
711    LANGUAGE SQL;
712
713SELECT * FROM dup(42);
714</programlisting>
715   However, a <literal>TABLE</literal> function is different from the
716   preceding examples, because it actually returns a <emphasis>set</emphasis>
717   of records, not just one record.
718  </para>
719 </refsect1>
720
721 <refsect1 id="sql-createfunction-security">
722  <title>Writing <literal>SECURITY DEFINER</literal> Functions Safely</title>
723
724  <indexterm>
725   <primary><varname>search_path</varname> configuration parameter</primary>
726   <secondary>use in securing functions</secondary>
727  </indexterm>
728
729   <para>
730    Because a <literal>SECURITY DEFINER</literal> function is executed
731    with the privileges of the user that owns it, care is needed to
732    ensure that the function cannot be misused.  For security,
733    <xref linkend="guc-search-path"/> should be set to exclude any schemas
734    writable by untrusted users.  This prevents
735    malicious users from creating objects (e.g., tables, functions, and
736    operators) that mask objects intended to be used by the function.
737    Particularly important in this regard is the
738    temporary-table schema, which is searched first by default, and
739    is normally writable by anyone.  A secure arrangement can be obtained
740    by forcing the temporary schema to be searched last.  To do this,
741    write <literal>pg_temp</literal><indexterm><primary>pg_temp</primary><secondary>securing functions</secondary></indexterm> as the last entry in <varname>search_path</varname>.
742    This function illustrates safe usage:
743
744<programlisting>
745CREATE FUNCTION check_password(uname TEXT, pass TEXT)
746RETURNS BOOLEAN AS $$
747DECLARE passed BOOLEAN;
748BEGIN
749        SELECT  (pwd = $2) INTO passed
750        FROM    pwds
751        WHERE   username = $1;
752
753        RETURN passed;
754END;
755$$  LANGUAGE plpgsql
756    SECURITY DEFINER
757    -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
758    SET search_path = admin, pg_temp;
759</programlisting>
760
761    This function's intention is to access a table <literal>admin.pwds</literal>.
762    But without the <literal>SET</literal> clause, or with a <literal>SET</literal> clause
763    mentioning only <literal>admin</literal>, the function could be subverted by
764    creating a temporary table named <literal>pwds</literal>.
765   </para>
766
767   <para>
768    Before <productname>PostgreSQL</productname> version 8.3, the
769    <literal>SET</literal> clause was not available, and so older functions may
770    contain rather complicated logic to save, set, and restore
771    <varname>search_path</varname>.  The <literal>SET</literal> clause is far easier
772    to use for this purpose.
773   </para>
774
775   <para>
776    Another point to keep in mind is that by default, execute privilege
777    is granted to <literal>PUBLIC</literal> for newly created functions
778    (see <xref linkend="ddl-priv"/> for more
779    information).  Frequently you will wish to restrict use of a security
780    definer function to only some users.  To do that, you must revoke
781    the default <literal>PUBLIC</literal> privileges and then grant execute
782    privilege selectively.  To avoid having a window where the new function
783    is accessible to all, create it and set the privileges within a single
784    transaction.  For example:
785   </para>
786
787<programlisting>
788BEGIN;
789CREATE FUNCTION check_password(uname TEXT, pass TEXT) ... SECURITY DEFINER;
790REVOKE ALL ON FUNCTION check_password(uname TEXT, pass TEXT) FROM PUBLIC;
791GRANT EXECUTE ON FUNCTION check_password(uname TEXT, pass TEXT) TO admins;
792COMMIT;
793</programlisting>
794
795 </refsect1>
796
797 <refsect1 id="sql-createfunction-compat">
798  <title>Compatibility</title>
799
800  <para>
801   A <command>CREATE FUNCTION</command> command is defined in the SQL standard.
802   The <productname>PostgreSQL</productname> version is similar but
803   not fully compatible.  The attributes are not portable, neither are the
804   different available languages.
805  </para>
806
807  <para>
808   For compatibility with some other database systems,
809   <replaceable class="parameter">argmode</replaceable> can be written
810   either before or after <replaceable class="parameter">argname</replaceable>.
811   But only the first way is standard-compliant.
812  </para>
813
814  <para>
815   For parameter defaults, the SQL standard specifies only the syntax with
816   the <literal>DEFAULT</literal> key word.  The syntax
817   with <literal>=</literal> is used in T-SQL and Firebird.
818  </para>
819 </refsect1>
820
821
822 <refsect1>
823  <title>See Also</title>
824
825  <simplelist type="inline">
826   <member><xref linkend="sql-alterfunction"/></member>
827   <member><xref linkend="sql-dropfunction"/></member>
828   <member><xref linkend="sql-grant"/></member>
829   <member><xref linkend="sql-load"/></member>
830   <member><xref linkend="sql-revoke"/></member>
831  </simplelist>
832 </refsect1>
833
834</refentry>
835