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
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>CREATE FUNCTION</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="sql-commands.html" title="SQL Commands">
<link rel="prev" href="sql-createdomain.html" title="CREATE DOMAIN">
<link rel="next" href="sql-creategroup.html" title="CREATE GROUP">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="refentry" lang="en">
<a name="sql-createfunction"></a><div class="titlepage"></div>
<div class="refnamediv">
<h2>Name</h2>
<p>CREATE FUNCTION — define a new function</p>
</div>
<a name="id755155"></a><div class="refsynopsisdiv">
<h2>Synopsis</h2>
<pre class="synopsis">CREATE [ OR REPLACE ] FUNCTION
<em class="replaceable"><code>name</code></em> ( [ [ <em class="replaceable"><code>argmode</code></em> ] [ <em class="replaceable"><code>argname</code></em> ] <em class="replaceable"><code>argtype</code></em> [, ...] ] )
[ RETURNS <em class="replaceable"><code>rettype</code></em> ]
{ LANGUAGE <em class="replaceable"><code>langname</code></em>
| IMMUTABLE | STABLE | VOLATILE
| CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
| [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
| AS '<em class="replaceable"><code>definition</code></em>'
| AS '<em class="replaceable"><code>obj_file</code></em>', '<em class="replaceable"><code>link_symbol</code></em>'
} ...
[ WITH ( <em class="replaceable"><code>attribute</code></em> [, ...] ) ]</pre>
</div>
<div class="refsect1" lang="en">
<a name="sql-createfunction-description"></a><h2>Description</h2>
<p> <code class="command">CREATE FUNCTION</code> defines a new function.
<code class="command">CREATE OR REPLACE FUNCTION</code> will either create a
new function, or replace an existing definition.
</p>
<p> If a schema name is included, then the function is created in the
specified schema. Otherwise it is created in the 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 <em class="firstterm">overloading</em>).
</p>
<p> To update the definition of an existing function, use
<code class="command">CREATE OR REPLACE FUNCTION</code>. It is not possible
to change the name or argument types of a function this way (if you
tried, you would actually be creating a new, distinct function).
Also, <code class="command">CREATE OR REPLACE FUNCTION</code> will not let
you change the return type of an existing function. To do that,
you must drop and recreate the function. (When using <code class="literal">OUT</code>
parameters, that means you can't change the names or types of any
<code class="literal">OUT</code> parameters except by dropping the function.)
</p>
<p> If you drop and then recreate a function, the new function is not
the same entity as the old; you will have to drop existing rules, views,
triggers, etc. that refer to the old function. Use
<code class="command">CREATE OR REPLACE FUNCTION</code> to change a function
definition without breaking objects that refer to the function.
</p>
<p> The user that creates the function becomes the owner of the function.
</p>
</div>
<div class="refsect1" lang="en">
<a name="id755338"></a><h2>Parameters</h2>
<div class="variablelist"><dl>
<dt><span class="term"><em class="replaceable"><code>name</code></em></span></dt>
<dd><p> The name (optionally schema-qualified) of the function to create.
</p></dd>
<dt><span class="term"><em class="replaceable"><code>argmode</code></em></span></dt>
<dd><p> The mode of an argument: either <code class="literal">IN</code>, <code class="literal">OUT</code>,
or <code class="literal">INOUT</code>. If omitted, the default is <code class="literal">IN</code>.
</p></dd>
<dt><span class="term"><em class="replaceable"><code>argname</code></em></span></dt>
<dd><p> The name of an argument. Some languages (currently only PL/pgSQL) let
you use the name in the function body. For other languages the
name of an input argument is just extra documentation. But the name
of an output argument is significant, since it defines the column
name in the result row type. (If you omit the name for an output
argument, the system will choose a default column name.)
</p></dd>
<dt><span class="term"><em class="replaceable"><code>argtype</code></em></span></dt>
<dd>
<p> The data type(s) of the function's arguments (optionally
schema-qualified), if any. The argument types may be base, composite,
or domain types, or may reference the type of a table column.
</p>
<p> Depending on the implementation language it may also be allowed
to specify “<span class="quote">pseudotypes</span>” such as <code class="type">cstring</code>.
Pseudotypes indicate that the actual argument type is either
incompletely specified, or outside the set of ordinary SQL data types.
</p>
<p> The type of a column is referenced by writing
<code class="literal"><em class="replaceable"><code>tablename</code></em>.<em class="replaceable"><code>columnname</code></em>%TYPE</code>.
Using this feature can sometimes help make a function independent of
changes to the definition of a table.
</p>
</dd>
<dt><span class="term"><em class="replaceable"><code>rettype</code></em></span></dt>
<dd>
<p> The return data type (optionally schema-qualified). The return type
may be a base, composite, or domain type,
or may reference the type of a table column.
Depending on the implementation language it may also be allowed
to specify “<span class="quote">pseudotypes</span>” such as <code class="type">cstring</code>.
</p>
<p> When there are <code class="literal">OUT</code> or <code class="literal">INOUT</code> parameters,
the <code class="literal">RETURNS</code> clause may be omitted. If present, it
must agree with the result type implied by the output parameters:
<code class="literal">RECORD</code> if there are multiple output parameters, or
the same type as the single output parameter.
</p>
<p> The <code class="literal">SETOF</code>
modifier indicates that the function will return a set of
items, rather than a single item.
</p>
<p> The type of a column is referenced by writing
<code class="literal"><em class="replaceable"><code>tablename</code></em>.<em class="replaceable"><code>columnname</code></em>%TYPE</code>.
</p>
</dd>
<dt><span class="term"><em class="replaceable"><code>langname</code></em></span></dt>
<dd><p> The name of the language that the function is implemented in.
May be <code class="literal">SQL</code>, <code class="literal">C</code>,
<code class="literal">internal</code>, or the name of a user-defined
procedural language. For backward compatibility,
the name may be enclosed by single quotes.
</p></dd>
<dt>
<span xmlns="http://www.w3.org/TR/xhtml1/transitional" class="term"><code xmlns="" class="literal">IMMUTABLE</code></span><br xmlns="http://www.w3.org/TR/xhtml1/transitional"></br><span xmlns="http://www.w3.org/TR/xhtml1/transitional" class="term"><code xmlns="" class="literal">STABLE</code></span><br xmlns="http://www.w3.org/TR/xhtml1/transitional"></br><span class="term"><code class="literal">VOLATILE</code></span>
</dt>
<dd>
<p> 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
may be specified. If none of these appear,
<code class="literal">VOLATILE</code> is the default assumption.
</p>
<p> <code class="literal">IMMUTABLE</code> 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 argument list. If this option is given,
any call of the function with all-constant arguments can be
immediately replaced with the function value.
</p>
<p> <code class="literal">STABLE</code> 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 <code class="function">current_timestamp</code> family of functions qualify
as stable, since their values do not change within a transaction.
</p>
<p> <code class="literal">VOLATILE</code> 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 <code class="literal">random()</code>, <code class="literal">currval()</code>,
<code class="literal">timeofday()</code>. But 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
<code class="literal">setval()</code>.
</p>
<p> For additional details see <a href="xfunc-volatility.html" title="32.6.Function Volatility Categories">Section32.6, “Function Volatility Categories”</a>.
</p>
</dd>
<dt>
<span xmlns="http://www.w3.org/TR/xhtml1/transitional" class="term"><code xmlns="" class="literal">CALLED ON NULL INPUT</code></span><br xmlns="http://www.w3.org/TR/xhtml1/transitional"></br><span xmlns="http://www.w3.org/TR/xhtml1/transitional" class="term"><code xmlns="" class="literal">RETURNS NULL ON NULL INPUT</code></span><br xmlns="http://www.w3.org/TR/xhtml1/transitional"></br><span class="term"><code class="literal">STRICT</code></span>
</dt>
<dd>
<p> <code class="literal">CALLED ON NULL INPUT</code> (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.
</p>
<p> <code class="literal">RETURNS NULL ON NULL INPUT</code> or
<code class="literal">STRICT</code> 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.
</p>
</dd>
<dt>
<span xmlns="http://www.w3.org/TR/xhtml1/transitional" class="term"><code xmlns="" class="literal">[<span class="optional">EXTERNAL</span>] SECURITY INVOKER</code></span><br xmlns="http://www.w3.org/TR/xhtml1/transitional"></br><span class="term"><code class="literal">[<span class="optional">EXTERNAL</span>] SECURITY DEFINER</code></span>
</dt>
<dd>
<p> <code class="literal">SECURITY INVOKER</code> indicates that the function
is to be executed with the privileges of the user that calls it.
That is the default. <code class="literal">SECURITY DEFINER</code>
specifies that the function is to be executed with the
privileges of the user that created it.
</p>
<p> The key word <code class="literal">EXTERNAL</code> is allowed for SQL
conformance, but it is optional since, unlike in SQL, this feature
applies to all functions not only external ones.
</p>
</dd>
<dt><span class="term"><em class="replaceable"><code>definition</code></em></span></dt>
<dd><p> A string constant defining the function; the meaning depends on the
language. It may be an internal function name, the path to an
object file, an SQL command, or text in a procedural language.
</p></dd>
<dt><span class="term"><code class="literal"><em class="replaceable"><code>obj_file</code></em>, <em class="replaceable"><code>link_symbol</code></em></code></span></dt>
<dd><p> This form of the <code class="literal">AS</code> clause is used for
dynamically loadable 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 <em class="replaceable"><code>obj_file</code></em> is the name of the
file containing the dynamically loadable object, and
<em class="replaceable"><code>link_symbol</code></em> is the
function's link symbol, that is, the name of the function in the C
language source code. If the link symbol is omitted, it is assumed
to be the same as the name of the SQL function being defined.
</p></dd>
<dt><span class="term"><em class="replaceable"><code>attribute</code></em></span></dt>
<dd>
<p> The historical way to specify optional pieces of information
about the function. The following attributes may appear here:
</p>
<div class="variablelist"><dl>
<dt><span class="term"><code class="literal">isStrict</code></span></dt>
<dd><p> Equivalent to <code class="literal">STRICT</code> or <code class="literal">RETURNS NULL ON NULL INPUT</code>.
</p></dd>
<dt><span class="term"><code class="literal">isCachable</code></span></dt>
<dd><p> <code class="literal">isCachable</code> is an obsolete equivalent of
<code class="literal">IMMUTABLE</code>; it's still accepted for
backwards-compatibility reasons.
</p></dd>
</dl></div>
<p>
Attribute names are not case-sensitive.
</p>
</dd>
</dl></div>
</div>
<div class="refsect1" lang="en">
<a name="sql-createfunction-notes"></a><h2>Notes</h2>
<p> Refer to <a href="xfunc.html" title="32.3.User-Defined Functions">Section32.3, “User-Defined Functions”</a> for further information on writing
functions.
</p>
<p> The full <acronym class="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 <code class="type">numeric</code>) are the responsibility of the
underlying function implementation and are silently swallowed
(i.e., not recognized or
enforced) by the <code class="command">CREATE FUNCTION</code> command.
</p>
<p> <span class="productname">PostgreSQL</span> allows function
<em class="firstterm">overloading</em>; that is, the same name can be
used for several different functions so long as they have distinct
argument types. However, the C names of all functions must be
different, so you must give overloaded C functions different C
names (for example, use the argument types as part of the C
names).
</p>
<p> Two functions are considered the same if they have the same names and
<span class="emphasis"><em>input</em></span> argument types, ignoring any <code class="literal">OUT</code>
parameters. Thus for example these declarations conflict:
</p>
<pre class="programlisting">CREATE FUNCTION foo(int) ...
CREATE FUNCTION foo(int, out text) ...</pre>
<p>
</p>
<p> When repeated <code class="command">CREATE FUNCTION</code> calls refer to
the same object file, the file is only loaded once. To unload and
reload the file (perhaps during development), use the <a href="sql-load.html">LOAD</a> command.
</p>
<p> Use <a href="sql-dropfunction.html">DROP FUNCTION</a> to remove user-defined
functions.
</p>
<p> It is often helpful to use dollar quoting (see <a href="sql-syntax.html#sql-syntax-dollar-quoting" title="4.1.2.2.Dollar-Quoted String Constants">Section4.1.2.2, “Dollar-Quoted String Constants”</a>) to write the function definition
string, rather than the normal single quote syntax. Without dollar
quoting, any single quotes or backslashes in the function definition must
be escaped by doubling them.
</p>
<p> To be able to define a function, the user must have the
<code class="literal">USAGE</code> privilege on the language.
</p>
</div>
<div class="refsect1" lang="en">
<a name="sql-createfunction-examples"></a><h2>Examples</h2>
<p> Here are some trivial examples to help you get started. For more
information and examples, see <a href="xfunc.html" title="32.3.User-Defined Functions">Section32.3, “User-Defined Functions”</a>.
</p>
<pre class="programlisting">CREATE FUNCTION add(integer, integer) RETURNS integer
AS 'select $1 + $2;'
LANGUAGE SQL
IMMUTABLE
RETURNS NULL ON NULL INPUT;</pre>
<p>
</p>
<p> Increment an integer, making use of an argument name, in
<span class="application">PL/pgSQL</span>:
</p>
<pre class="programlisting">CREATE OR REPLACE FUNCTION increment(i integer) RETURNS integer AS $$
BEGIN
RETURN i + 1;
END;
$$ LANGUAGE plpgsql;</pre>
<p>
</p>
<p> Return a record containing multiple output parameters:
</p>
<pre class="programlisting">CREATE FUNCTION dup(in int, out f1 int, out f2 text)
AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
LANGUAGE SQL;
SELECT * FROM dup(42);</pre>
<p>
You can do the same thing more verbosely with an explicitly named
composite type:
</p>
<pre class="programlisting">CREATE TYPE dup_result AS (f1 int, f2 text);
CREATE FUNCTION dup(int) RETURNS dup_result
AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
LANGUAGE SQL;
SELECT * FROM dup(42);</pre>
<p>
</p>
</div>
<div class="refsect1" lang="en">
<a name="sql-createfunction-compat"></a><h2>Compatibility</h2>
<p> A <code class="command">CREATE FUNCTION</code> command is defined in SQL:1999 and later.
The <span class="productname">PostgreSQL</span> version is similar but
not fully compatible. The attributes are not portable, neither are the
different available languages.
</p>
<p> For compatibility with some other database systems,
<em class="replaceable"><code>argmode</code></em> can be written
either before or after <em class="replaceable"><code>argname</code></em>.
But only the first way is standard-compliant.
</p>
</div>
<div class="refsect1" lang="en">
<a name="id756226"></a><h2>See Also</h2>
<span class="simplelist"><a href="sql-alterfunction.html">ALTER FUNCTION</a>, <a href="sql-dropfunction.html">DROP FUNCTION</a>, <a href="sql-grant.html">GRANT</a>, <a href="sql-load.html">LOAD</a>, <a href="sql-revoke.html">REVOKE</a>, <a href="app-createlang.html"><span class="application">createlang</span></a></span>
</div>
</div></body>
</html>
|