aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/create_function.sgml
blob: 6c737f26141528f7377aa5c5381fc714d153a8d6 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_function.sgml,v 1.43 2002/09/21 18:32:54 petere Exp $
-->

<refentry id="SQL-CREATEFUNCTION">
 <refmeta>
  <refentrytitle id="SQL-CREATEFUNCTION-TITLE">CREATE FUNCTION</refentrytitle>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>CREATE FUNCTION</refname>
  <refpurpose>define a new function</refpurpose>
 </refnamediv>

 <refsynopsisdiv>
<synopsis>
CREATE [ OR REPLACE ] FUNCTION <replaceable class="parameter">name</replaceable> ( [ <replaceable class="parameter">argtype</replaceable> [, ...] ] )
    RETURNS <replaceable class="parameter">rettype</replaceable>
  { LANGUAGE <replaceable class="parameter">langname</replaceable>
    | IMMUTABLE | STABLE | VOLATILE
    | CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
    | [EXTERNAL] SECURITY INVOKER | [EXTERNAL] SECURITY DEFINER
    | AS '<replaceable class="parameter">definition</replaceable>'
    | AS '<replaceable class="parameter">obj_file</replaceable>', '<replaceable class="parameter">link_symbol</replaceable>'
  } ...
    [ WITH ( <replaceable class="parameter">attribute</replaceable> [, ...] ) ]
</synopsis>
 </refsynopsisdiv>
  
 <refsect1 id="sql-createfunction-description">
  <title>Description</title>

  <para>
   <command>CREATE FUNCTION</command> defines a new function.
   <command>CREATE OR REPLACE FUNCTION</command> will either create a
   new function, or replace an existing definition.
  </para>

  <para>
   The user that creates the function becomes the owner of the function.
  </para>

   <variablelist>
    <title>Parameters</title>

    <varlistentry>
     <term><replaceable class="parameter">name</replaceable></term>

     <listitem>
      <para>
       The name of a function to create.  If a schema name is included,
       then the function is created in the
       specified schema.  Otherwise it is created in the current schema (the
       one at the front of the search path; see <literal>CURRENT_SCHEMA()</>).
       The name of the new function must not match any existing function
       with the same argument types in the same schema.  However, functions of
       different argument types may share a name (this is called
       <firstterm>overloading</>).
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><replaceable class="parameter">argtype</replaceable></term>

     <listitem>
      <para>
       The data type(s) of the function's arguments, if any.  The
       input types may be base, complex, or domain types,
       or the same as the type of an existing column.
	The type of a column is referenced by writing <replaceable
	class="parameter">tablename</replaceable>.<replaceable
	class="parameter">columnname</replaceable><literal>%TYPE</literal>;
	using this can sometimes help make a function independent from
	changes to the definition of a table.
	Depending on the implementation language it may also be allowed
	to specify <quote>pseudo-types</> such as <type>cstring</>.
	Pseudo-types indicate that the actual argument type is either
	incompletely specified, or outside the set of ordinary SQL data types.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><replaceable class="parameter">rettype</replaceable></term>

     <listitem>
      <para>
       The return data type.  The return type may be specified as a
       base, complex, or domain type, or the same as the type of an
       existing column.
       Depending on the implementation language it may also be allowed
       to specify <quote>pseudo-types</> such as <type>cstring</>.
       The <literal>setof</literal>
       modifier indicates that the function will return a set of
       items, rather than a single item.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><replaceable class="parameter">langname</replaceable></term>

     <listitem>
      <para>
       The name of the language that the function is implemented in.
       May be <literal>SQL</literal>, <literal>C</literal>,
       <literal>internal</literal>, or the name of a user-defined
       procedural language.  (See also <xref linkend="app-createlang"
       endterm="app-createlang-title">.)  For backward compatibility,
       the name may be enclosed by single quotes.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term>IMMUTABLE</term>
     <term>STABLE</term>
     <term>VOLATILE</term>

     <listitem>
      <para>
       These attributes inform the system whether it is safe to
       replace multiple evaluations of the function with a single
       evaluation, for run-time optimization.  At most one choice
       should be specified.  If none of these appear,
       <literal>VOLATILE</literal> is the default assumption.
      </para>

      <para>
       <literal>IMMUTABLE</literal> indicates that the function always
       returns the same result when given the same argument values; that
       is, it does not do database lookups or otherwise use information not
       directly present in its parameter list.  If this option is given,
       any call of the function with all-constant arguments can be
       immediately replaced with the function value.
      </para>

      <para>
       <literal>STABLE</literal> indicates that within a single table scan
       the function will consistently
       return the same result for the same argument values, but that its
       result could change across SQL statements.  This is the appropriate
       selection for functions whose results depend on database lookups,
       parameter variables (such as the current time zone), etc.  Also note
       that the <literal>CURRENT_TIMESTAMP</> family of functions qualify
       as stable, since their values do not change within a transaction.
      </para>

      <para>
       <literal>VOLATILE</literal> indicates that the function value can
       change even within a single table scan, so no optimizations can be
       made.  Relatively few database functions are volatile in this sense;
       some examples are <literal>random()</>, <literal>currval()</>,
       <literal>timeofday()</>.  Note that any function that has side-effects
       must be classified volatile, even if its result is quite predictable,
       to prevent calls from being optimized away; an example is
       <literal>setval()</>.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term>CALLED ON NULL INPUT</term>
     <term>RETURNS NULL ON NULL INPUT</term>
     <term>STRICT</term>

     <listitem>
      <para>
       <literal>CALLED ON NULL INPUT</literal> (the default) indicates
       that the function will be called normally when some of its
       arguments are null.  It is then the function author's
       responsibility to check for null values if necessary and respond
       appropriately.
      </para>

      <para>
       <literal>RETURNS NULL ON NULL INPUT</literal> or
       <literal>STRICT</literal> indicates that the function always
       returns NULL whenever any of its arguments are NULL.  If this
       parameter is specified, the function is not executed when there
       are NULL arguments; instead a NULL result is assumed
       automatically.
      </para>
     </listitem>
    </varlistentry>

   <varlistentry>
    <term><optional>EXTERNAL</optional> SECURITY INVOKER</term>
    <term><optional>EXTERNAL</optional> SECURITY DEFINER</term>

    <listitem>
     <para>
      <literal>SECURITY INVOKER</literal> indicates that the function
      is to be executed with the privileges of the user that calls it.
      That is the default.  <literal>SECURITY DEFINER</literal>
      specifies that the function is to be executed with the
      privileges of the user that created it.
     </para>

     <para>
      The key word <literal>EXTERNAL</literal> is present for SQL
      compatibility but is optional since, unlike in SQL, this feature
      does not only apply to external functions.
     </para>
    </listitem>
   </varlistentry>

    <varlistentry>
     <term><replaceable class="parameter">definition</replaceable></term>

     <listitem>
      <para>
       A string defining the function; the meaning depends on the
       language.  It may be an internal function name, the path to an
       object file, an SQL query, or text in a procedural language.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><replaceable class="parameter">obj_file</replaceable>, <replaceable class="parameter">link_symbol</replaceable></term>

     <listitem>
      <para>
       This form of the <literal>AS</literal> clause is used for
       dynamically linked C language functions when the function name
       in the C language source code is not the same as the name of
       the SQL function. The string <replaceable
       class="parameter">obj_file</replaceable> is the name of the
       file containing the dynamically loadable object, and
       <replaceable class="parameter">link_symbol</replaceable> is the
       object's link symbol, that is, the name of the function in the C
       language source code.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><replaceable class="parameter">attribute</replaceable></term>

     <listitem>
      <para>
       The historical way to specify optional pieces of information
       about the function.  The following attributes may appear here:

      <variablelist>
       <varlistentry>
        <term><literal>isStrict</></term>
        <listitem>
         <para>
          Equivalent to <literal>STRICT</literal> or <literal>RETURNS NULL ON NULL INPUT</literal>
         </para>
        </listitem>
       </varlistentry>

       <varlistentry>
        <term><literal>isCachable</></term>
        <listitem>
         <para>
          <literal>isCachable</literal> is an obsolete equivalent of
          <literal>IMMUTABLE</literal>; it's still accepted for
          backwards-compatibility reasons.
         </para>
        </listitem>
       </varlistentry>

      </variablelist>

      Attribute names are not case-sensitive.
     </para>
    </listitem>
   </varlistentry>

   </variablelist>

 </refsect1>

 <refsect1 id="sql-createfunction-notes">
  <title>Notes</title>

   <para>
    Refer to the chapter in the
    <citetitle>PostgreSQL Programmer's Guide</citetitle>
    on the topic of extending
    <productname>PostgreSQL</productname> via functions 
    for further information on writing external functions.
   </para>

   <para>
    The full <acronym>SQL</acronym> type syntax is allowed for
    input arguments and return value. However, some details of the
    type specification (e.g., the precision field for
    <type>numeric</type> types) are the responsibility of the
    underlying function implementation and are silently swallowed
    (i.e., not recognized or
    enforced) by the <command>CREATE FUNCTION</command> command.
   </para>

   <para>
    <productname>PostgreSQL</productname> allows function <firstterm>overloading</firstterm>;
    that is, the same name can be used for several different functions
    so long as they have distinct argument types.  This facility must
    be used with caution for internal and C-language functions, however.    
   </para>

   <para>
    Two <literal>internal</literal>
    functions cannot have the same C name without causing
    errors at link time.  To get around that, give them different C names
    (for example, use the argument types as part of the C names), then
    specify those names in the AS clause of <command>CREATE FUNCTION</command>.
    If the AS clause is left empty, then <command>CREATE FUNCTION</command>
    assumes the C name of the function is the same as the SQL name.
   </para>

   <para>
    Similarly, when overloading SQL function names with multiple C-language
    functions, give
    each C-language instance of the function a distinct name, then use
    the alternative form of the <command>AS</command> clause in the
    <command>CREATE FUNCTION</command> syntax to select the appropriate
    C-language implementation of each overloaded SQL function.
   </para>

   <para>
    When repeated <command>CREATE FUNCTION</command> calls refer to
    the same object file, the file is only loaded once.  To unload and
    reload the file (perhaps during development), use the <xref
    linkend="sql-load" endterm="sql-load-title"> command.
   </para>

   <para>
    Use <command>DROP FUNCTION</command>
    to remove user-defined functions.
   </para>

   <para>
    To update the definition of an existing function, use
    <command>CREATE OR REPLACE FUNCTION</command>.  Note that it is
    not possible to change the name or argument types of a function
    this way (if you tried, you'd just be creating a new, distinct
    function).  Also, <command>CREATE OR REPLACE FUNCTION</command>
    will not let you change the return type of an existing function.
    To do that, you must drop and re-create the function.
   </para>

   <para>
    If you drop and then re-create a function, the new function is not
    the same entity as the old; you will break existing rules, views,
    triggers, etc that referred to the old function.  Use 
    <command>CREATE OR REPLACE FUNCTION</command> to change a function
    definition without breaking objects that refer to the function.
   </para>

  <para>
   To be able to define a function, the user must have the
   <literal>USAGE</literal> privilege on the language.
  </para>

  <para>
   By default, only the owner (creator) of the function has the right
   to execute it.  Other users must be granted the
   <literal>EXECUTE</literal> privilege on the function to be able to
   use it.
  </para>
 </refsect1>

 <refsect1 id="sql-createfunction-examples">
  <title>Examples</title>

  <para>
   To create a simple SQL function:

<programlisting>
CREATE FUNCTION one() RETURNS integer
    AS 'SELECT 1 AS RESULT;'
    LANGUAGE SQL;

SELECT one() AS answer;
<computeroutput>
 answer 
--------
      1
</computeroutput>
</programlisting>
  </para>

  <para>
   The next example creates a C function by calling a routine from a
   user-created shared library named <filename>funcs.so</> (the extension
   may vary across platforms).  The shared library file is sought in the
   server's dynamic library search path.  This particular routine calculates
   a check digit and returns true if the check digit in the function
   parameters is correct.  It is intended for use in a CHECK
   constraint.

<programlisting>
CREATE FUNCTION ean_checkdigit(char, char) RETURNS boolean
    AS 'funcs' LANGUAGE C;
    
CREATE TABLE product (
    id        char(8) PRIMARY KEY,
    eanprefix char(8) CHECK (eanprefix ~ '[0-9]{2}-[0-9]{5}')
                      REFERENCES brandname(ean_prefix),
    eancode   char(6) CHECK (eancode ~ '[0-9]{6}'),
    CONSTRAINT ean    CHECK (ean_checkdigit(eanprefix, eancode))
);
</programlisting>
  </para>

  <para>
   The next example creates a function that does type conversion from the
   user-defined type complex to the built-in type point.  The
   function is implemented by a dynamically loaded object that was
   compiled from C source (we illustrate the now-deprecated alternative
   of specifying the absolute file name to the shared object file).
   For <productname>PostgreSQL</productname> to
   find a type conversion function automatically, the SQL function has
   to have the same name as the return type, and so overloading is
   unavoidable.  The function name is overloaded by using the second
   form of the <command>AS</command> clause in the SQL definition:

<programlisting>
CREATE FUNCTION point(complex) RETURNS point
    AS '/home/bernie/pgsql/lib/complex.so', 'complex_to_point'
    LANGUAGE C STRICT;
</programlisting>

  The C declaration of the function could be:

<programlisting>
Point * complex_to_point (Complex *z)
{
	Point *p;

	p = (Point *) palloc(sizeof(Point));
	p->x = z->x;
	p->y = z->y;
		
	return p;
}
</programlisting>

   Note that the function is marked <quote>strict</>; this allows us
   to skip checking for NULL input in the function body.
  </para>    
 </refsect1>

 
 <refsect1 id="sql-createfunction-compat">
  <title>Compatibility</title>

  <para>
   A <command>CREATE FUNCTION</command> command is defined in SQL99.
   The <application>PostgreSQL</application> version is similar but
   not fully compatible.  The attributes are not portable, neither are the
   different available languages.
  </para>
 </refsect1>


 <refsect1 id="sql-createfunction-seealso">
  <title>See Also</title>

  <para>
   <xref linkend="sql-dropfunction" endterm="sql-dropfunction-title">,
   <xref linkend="sql-grant" endterm="sql-grant-title">,
   <xref linkend="sql-load" endterm="sql-load-title">,
   <xref linkend="sql-revoke" endterm="sql-revoke-title">,
   <xref linkend="app-createlang">,
   <citetitle>PostgreSQL Programmer's Guide</citetitle>
  </para>
 </refsect1>

</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->