1CREATE FUNCTION(7) PostgreSQL 12.6 Documentation CREATE FUNCTION(7)
2
3
4
6 CREATE_FUNCTION - define a new function
7
9 CREATE [ OR REPLACE ] FUNCTION
10 name ( [ [ argmode ] [ argname ] argtype [ { DEFAULT | = } default_expr ] [, ...] ] )
11 [ RETURNS rettype
12 | RETURNS TABLE ( column_name column_type [, ...] ) ]
13 { LANGUAGE lang_name
14 | TRANSFORM { FOR TYPE type_name } [, ... ]
15 | WINDOW
16 | IMMUTABLE | STABLE | VOLATILE | [ NOT ] LEAKPROOF
17 | CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
18 | [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
19 | PARALLEL { UNSAFE | RESTRICTED | SAFE }
20 | COST execution_cost
21 | ROWS result_rows
22 | SUPPORT support_function
23 | SET configuration_parameter { TO value | = value | FROM CURRENT }
24 | AS 'definition'
25 | AS 'obj_file', 'link_symbol'
26 } ...
27
29 CREATE FUNCTION defines a new function. CREATE OR REPLACE FUNCTION
30 will either create a new function, or replace an existing definition.
31 To be able to define a function, the user must have the USAGE privilege
32 on the language.
33
34 If a schema name is included, then the function is created in the
35 specified schema. Otherwise it is created in the current schema. The
36 name of the new function must not match any existing function or
37 procedure with the same input argument types in the same schema.
38 However, functions and procedures of different argument types can share
39 a name (this is called overloading).
40
41 To replace the current definition of an existing function, use CREATE
42 OR REPLACE FUNCTION. It is not possible to change the name or argument
43 types of a function this way (if you tried, you would actually be
44 creating a new, distinct function). Also, CREATE OR REPLACE FUNCTION
45 will not let you change the return type of an existing function. To do
46 that, you must drop and recreate the function. (When using OUT
47 parameters, that means you cannot change the types of any OUT
48 parameters except by dropping the function.)
49
50 When CREATE OR REPLACE FUNCTION is used to replace an existing
51 function, the ownership and permissions of the function do not change.
52 All other function properties are assigned the values specified or
53 implied in the command. You must own the function to replace it (this
54 includes being a member of the owning role).
55
56 If you drop and then recreate a function, the new function is not the
57 same entity as the old; you will have to drop existing rules, views,
58 triggers, etc. that refer to the old function. Use CREATE OR REPLACE
59 FUNCTION to change a function definition without breaking objects that
60 refer to the function. Also, ALTER FUNCTION can be used to change most
61 of the auxiliary properties of an existing function.
62
63 The user that creates the function becomes the owner of the function.
64
65 To be able to create a function, you must have USAGE privilege on the
66 argument types and the return type.
67
69 name
70 The name (optionally schema-qualified) of the function to create.
71
72 argmode
73 The mode of an argument: IN, OUT, INOUT, or VARIADIC. If omitted,
74 the default is IN. Only OUT arguments can follow a VARIADIC one.
75 Also, OUT and INOUT arguments cannot be used together with the
76 RETURNS TABLE notation.
77
78 argname
79 The name of an argument. Some languages (including SQL and
80 PL/pgSQL) let you use the name in the function body. For other
81 languages the name of an input argument is just extra
82 documentation, so far as the function itself is concerned; but you
83 can use input argument names when calling a function to improve
84 readability (see Section 4.3). In any case, the name of an output
85 argument is significant, because it defines the column name in the
86 result row type. (If you omit the name for an output argument, the
87 system will choose a default column name.)
88
89 argtype
90 The data type(s) of the function's arguments (optionally
91 schema-qualified), if any. The argument types can be base,
92 composite, or domain types, or can reference the type of a table
93 column.
94
95 Depending on the implementation language it might also be allowed
96 to specify “pseudo-types” such as cstring. Pseudo-types indicate
97 that the actual argument type is either incompletely specified, or
98 outside the set of ordinary SQL data types.
99
100 The type of a column is referenced by writing
101 table_name.column_name%TYPE. Using this feature can sometimes help
102 make a function independent of changes to the definition of a
103 table.
104
105 default_expr
106 An expression to be used as default value if the parameter is not
107 specified. The expression has to be coercible to the argument type
108 of the parameter. Only input (including INOUT) parameters can have
109 a default value. All input parameters following a parameter with a
110 default value must have default values as well.
111
112 rettype
113 The return data type (optionally schema-qualified). The return type
114 can be a base, composite, or domain type, or can reference the type
115 of a table column. Depending on the implementation language it
116 might also be allowed to specify “pseudo-types” such as cstring. If
117 the function is not supposed to return a value, specify void as the
118 return type.
119
120 When there are OUT or INOUT parameters, the RETURNS clause can be
121 omitted. If present, it must agree with the result type implied by
122 the output parameters: RECORD if there are multiple output
123 parameters, or the same type as the single output parameter.
124
125 The SETOF modifier indicates that the function will return a set of
126 items, rather than a single item.
127
128 The type of a column is referenced by writing
129 table_name.column_name%TYPE.
130
131 column_name
132 The name of an output column in the RETURNS TABLE syntax. This is
133 effectively another way of declaring a named OUT parameter, except
134 that RETURNS TABLE also implies RETURNS SETOF.
135
136 column_type
137 The data type of an output column in the RETURNS TABLE syntax.
138
139 lang_name
140 The name of the language that the function is implemented in. It
141 can be sql, c, internal, or the name of a user-defined procedural
142 language, e.g., plpgsql. Enclosing the name in single quotes is
143 deprecated and requires matching case.
144
145 TRANSFORM { FOR TYPE type_name } [, ... ] }
146 Lists which transforms a call to the function should apply.
147 Transforms convert between SQL types and language-specific data
148 types; see CREATE TRANSFORM (CREATE_TRANSFORM(7)). Procedural
149 language implementations usually have hardcoded knowledge of the
150 built-in types, so those don't need to be listed here. If a
151 procedural language implementation does not know how to handle a
152 type and no transform is supplied, it will fall back to a default
153 behavior for converting data types, but this depends on the
154 implementation.
155
156 WINDOW
157 WINDOW indicates that the function is a window function rather than
158 a plain function. This is currently only useful for functions
159 written in C. The WINDOW attribute cannot be changed when replacing
160 an existing function definition.
161
162 IMMUTABLE
163 STABLE
164 VOLATILE
165 These attributes inform the query optimizer about the behavior of
166 the function. At most one choice can be specified. If none of these
167 appear, VOLATILE is the default assumption.
168
169 IMMUTABLE indicates that the function cannot modify the database
170 and always returns the same result when given the same argument
171 values; that is, it does not do database lookups or otherwise use
172 information not directly present in its argument list. If this
173 option is given, any call of the function with all-constant
174 arguments can be immediately replaced with the function value.
175
176 STABLE indicates that the function cannot modify the database, and
177 that within a single table scan it will consistently return the
178 same result for the same argument values, but that its result could
179 change across SQL statements. This is the appropriate selection for
180 functions whose results depend on database lookups, parameter
181 variables (such as the current time zone), etc. (It is
182 inappropriate for AFTER triggers that wish to query rows modified
183 by the current command.) Also note that the current_timestamp
184 family of functions qualify as stable, since their values do not
185 change within a transaction.
186
187 VOLATILE indicates that the function value can change even within a
188 single table scan, so no optimizations can be made. Relatively few
189 database functions are volatile in this sense; some examples are
190 random(), currval(), timeofday(). But note that any function that
191 has side-effects must be classified volatile, even if its result is
192 quite predictable, to prevent calls from being optimized away; an
193 example is setval().
194
195 For additional details see Section 37.7.
196
197 LEAKPROOF
198 LEAKPROOF indicates that the function has no side effects. It
199 reveals no information about its arguments other than by its return
200 value. For example, a function which throws an error message for
201 some argument values but not others, or which includes the argument
202 values in any error message, is not leakproof. This affects how the
203 system executes queries against views created with the
204 security_barrier option or tables with row level security enabled.
205 The system will enforce conditions from security policies and
206 security barrier views before any user-supplied conditions from the
207 query itself that contain non-leakproof functions, in order to
208 prevent the inadvertent exposure of data. Functions and operators
209 marked as leakproof are assumed to be trustworthy, and may be
210 executed before conditions from security policies and security
211 barrier views. In addition, functions which do not take arguments
212 or which are not passed any arguments from the security barrier
213 view or table do not have to be marked as leakproof to be executed
214 before security conditions. See CREATE VIEW (CREATE_VIEW(7)) and
215 Section 40.5. This option can only be set by the superuser.
216
217 CALLED ON NULL INPUT
218 RETURNS NULL ON NULL INPUT
219 STRICT
220 CALLED ON NULL INPUT (the default) indicates that the function will
221 be called normally when some of its arguments are null. It is then
222 the function author's responsibility to check for null values if
223 necessary and respond appropriately.
224
225 RETURNS NULL ON NULL INPUT or STRICT indicates that the function
226 always returns null whenever any of its arguments are null. If this
227 parameter is specified, the function is not executed when there are
228 null arguments; instead a null result is assumed automatically.
229
230 [EXTERNAL] SECURITY INVOKER
231 [EXTERNAL] SECURITY DEFINER
232 SECURITY INVOKER indicates that the function is to be executed with
233 the privileges of the user that calls it. That is the default.
234 SECURITY DEFINER specifies that the function is to be executed with
235 the privileges of the user that owns it.
236
237 The key word EXTERNAL is allowed for SQL conformance, but it is
238 optional since, unlike in SQL, this feature applies to all
239 functions not only external ones.
240
241 PARALLEL
242 PARALLEL UNSAFE indicates that the function can't be executed in
243 parallel mode and the presence of such a function in an SQL
244 statement forces a serial execution plan. This is the default.
245 PARALLEL RESTRICTED indicates that the function can be executed in
246 parallel mode, but the execution is restricted to parallel group
247 leader. PARALLEL SAFE indicates that the function is safe to run
248 in parallel mode without restriction.
249
250 Functions should be labeled parallel unsafe if they modify any
251 database state, or if they make changes to the transaction such as
252 using sub-transactions, or if they access sequences or attempt to
253 make persistent changes to settings (e.g., setval). They should be
254 labeled as parallel restricted if they access temporary tables,
255 client connection state, cursors, prepared statements, or
256 miscellaneous backend-local state which the system cannot
257 synchronize in parallel mode (e.g., setseed cannot be executed
258 other than by the group leader because a change made by another
259 process would not be reflected in the leader). In general, if a
260 function is labeled as being safe when it is restricted or unsafe,
261 or if it is labeled as being restricted when it is in fact unsafe,
262 it may throw errors or produce wrong answers when used in a
263 parallel query. C-language functions could in theory exhibit
264 totally undefined behavior if mislabeled, since there is no way for
265 the system to protect itself against arbitrary C code, but in most
266 likely cases the result will be no worse than for any other
267 function. If in doubt, functions should be labeled as UNSAFE, which
268 is the default.
269
270 COST execution_cost
271 A positive number giving the estimated execution cost for the
272 function, in units of cpu_operator_cost. If the function returns a
273 set, this is the cost per returned row. If the cost is not
274 specified, 1 unit is assumed for C-language and internal functions,
275 and 100 units for functions in all other languages. Larger values
276 cause the planner to try to avoid evaluating the function more
277 often than necessary.
278
279 ROWS result_rows
280 A positive number giving the estimated number of rows that the
281 planner should expect the function to return. This is only allowed
282 when the function is declared to return a set. The default
283 assumption is 1000 rows.
284
285 SUPPORT support_function
286 The name (optionally schema-qualified) of a planner support
287 function to use for this function. See Section 37.11 for details.
288 You must be superuser to use this option.
289
290 configuration_parameter
291 value
292 The SET clause causes the specified configuration parameter to be
293 set to the specified value when the function is entered, and then
294 restored to its prior value when the function exits. SET FROM
295 CURRENT saves the value of the parameter that is current when
296 CREATE FUNCTION is executed as the value to be applied when the
297 function is entered.
298
299 If a SET clause is attached to a function, then the effects of a
300 SET LOCAL command executed inside the function for the same
301 variable are restricted to the function: the configuration
302 parameter's prior value is still restored at function exit.
303 However, an ordinary SET command (without LOCAL) overrides the SET
304 clause, much as it would do for a previous SET LOCAL command: the
305 effects of such a command will persist after function exit, unless
306 the current transaction is rolled back.
307
308 See SET(7) and Chapter 19 for more information about allowed
309 parameter names and values.
310
311 definition
312 A string constant defining the function; the meaning depends on the
313 language. It can be an internal function name, the path to an
314 object file, an SQL command, or text in a procedural language.
315
316 It is often helpful to use dollar quoting (see Section 4.1.2.4) to
317 write the function definition string, rather than the normal single
318 quote syntax. Without dollar quoting, any single quotes or
319 backslashes in the function definition must be escaped by doubling
320 them.
321
322 obj_file, link_symbol
323 This form of the AS clause is used for dynamically loadable C
324 language functions when the function name in the C language source
325 code is not the same as the name of the SQL function. The string
326 obj_file is the name of the shared library file containing the
327 compiled C function, and is interpreted as for the LOAD(7) command.
328 The string link_symbol is the function's link symbol, that is, the
329 name of the function in the C language source code. If the link
330 symbol is omitted, it is assumed to be the same as the name of the
331 SQL function being defined. The C names of all functions must be
332 different, so you must give overloaded C functions different C
333 names (for example, use the argument types as part of the C names).
334
335 When repeated CREATE FUNCTION calls refer to the same object file,
336 the file is only loaded once per session. To unload and reload the
337 file (perhaps during development), start a new session.
338
339 Refer to Section 37.3 for further information on writing functions.
340
342 PostgreSQL allows function overloading; that is, the same name can be
343 used for several different functions so long as they have distinct
344 input argument types. Whether or not you use it, this capability
345 entails security precautions when calling functions in databases where
346 some users mistrust other users; see Section 10.3.
347
348 Two functions are considered the same if they have the same names and
349 input argument types, ignoring any OUT parameters. Thus for example
350 these declarations conflict:
351
352 CREATE FUNCTION foo(int) ...
353 CREATE FUNCTION foo(int, out text) ...
354
355 Functions that have different argument type lists will not be
356 considered to conflict at creation time, but if defaults are provided
357 they might conflict in use. For example, consider
358
359 CREATE FUNCTION foo(int) ...
360 CREATE FUNCTION foo(int, int default 42) ...
361
362 A call foo(10) will fail due to the ambiguity about which function
363 should be called.
364
366 The full SQL type syntax is allowed for declaring a function's
367 arguments and return value. However, parenthesized type modifiers
368 (e.g., the precision field for type numeric) are discarded by CREATE
369 FUNCTION. Thus for example CREATE FUNCTION foo (varchar(10)) ... is
370 exactly the same as CREATE FUNCTION foo (varchar) ....
371
372 When replacing an existing function with CREATE OR REPLACE FUNCTION,
373 there are restrictions on changing parameter names. You cannot change
374 the name already assigned to any input parameter (although you can add
375 names to parameters that had none before). If there is more than one
376 output parameter, you cannot change the names of the output parameters,
377 because that would change the column names of the anonymous composite
378 type that describes the function's result. These restrictions are made
379 to ensure that existing calls of the function do not stop working when
380 it is replaced.
381
382 If a function is declared STRICT with a VARIADIC argument, the
383 strictness check tests that the variadic array as a whole is non-null.
384 The function will still be called if the array has null elements.
385
387 Here are some trivial examples to help you get started. For more
388 information and examples, see Section 37.3.
389
390 CREATE FUNCTION add(integer, integer) RETURNS integer
391 AS 'select $1 + $2;'
392 LANGUAGE SQL
393 IMMUTABLE
394 RETURNS NULL ON NULL INPUT;
395
396 Increment an integer, making use of an argument name, in PL/pgSQL:
397
398 CREATE OR REPLACE FUNCTION increment(i integer) RETURNS integer AS $$
399 BEGIN
400 RETURN i + 1;
401 END;
402 $$ LANGUAGE plpgsql;
403
404 Return a record containing multiple output parameters:
405
406 CREATE FUNCTION dup(in int, out f1 int, out f2 text)
407 AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
408 LANGUAGE SQL;
409
410 SELECT * FROM dup(42);
411
412 You can do the same thing more verbosely with an explicitly named
413 composite type:
414
415 CREATE TYPE dup_result AS (f1 int, f2 text);
416
417 CREATE FUNCTION dup(int) RETURNS dup_result
418 AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
419 LANGUAGE SQL;
420
421 SELECT * FROM dup(42);
422
423 Another way to return multiple columns is to use a TABLE function:
424
425 CREATE FUNCTION dup(int) RETURNS TABLE(f1 int, f2 text)
426 AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$
427 LANGUAGE SQL;
428
429 SELECT * FROM dup(42);
430
431 However, a TABLE function is different from the preceding examples,
432 because it actually returns a set of records, not just one record.
433
435 Because a SECURITY DEFINER function is executed with the privileges of
436 the user that owns it, care is needed to ensure that the function
437 cannot be misused. For security, search_path should be set to exclude
438 any schemas writable by untrusted users. This prevents malicious users
439 from creating objects (e.g., tables, functions, and operators) that
440 mask objects intended to be used by the function. Particularly
441 important in this regard is the temporary-table schema, which is
442 searched first by default, and is normally writable by anyone. A secure
443 arrangement can be obtained by forcing the temporary schema to be
444 searched last. To do this, write pg_temp as the last entry in
445 search_path. This function illustrates safe usage:
446
447 CREATE FUNCTION check_password(uname TEXT, pass TEXT)
448 RETURNS BOOLEAN AS $$
449 DECLARE passed BOOLEAN;
450 BEGIN
451 SELECT (pwd = $2) INTO passed
452 FROM pwds
453 WHERE username = $1;
454
455 RETURN passed;
456 END;
457 $$ LANGUAGE plpgsql
458 SECURITY DEFINER
459 -- Set a secure search_path: trusted schema(s), then 'pg_temp'.
460 SET search_path = admin, pg_temp;
461
462 This function's intention is to access a table admin.pwds. But without
463 the SET clause, or with a SET clause mentioning only admin, the
464 function could be subverted by creating a temporary table named pwds.
465
466 Before PostgreSQL version 8.3, the SET clause was not available, and so
467 older functions may contain rather complicated logic to save, set, and
468 restore search_path. The SET clause is far easier to use for this
469 purpose.
470
471 Another point to keep in mind is that by default, execute privilege is
472 granted to PUBLIC for newly created functions (see Section 5.7 for more
473 information). Frequently you will wish to restrict use of a security
474 definer function to only some users. To do that, you must revoke the
475 default PUBLIC privileges and then grant execute privilege selectively.
476 To avoid having a window where the new function is accessible to all,
477 create it and set the privileges within a single transaction. For
478 example:
479
480 BEGIN;
481 CREATE FUNCTION check_password(uname TEXT, pass TEXT) ... SECURITY DEFINER;
482 REVOKE ALL ON FUNCTION check_password(uname TEXT, pass TEXT) FROM PUBLIC;
483 GRANT EXECUTE ON FUNCTION check_password(uname TEXT, pass TEXT) TO admins;
484 COMMIT;
485
487 A CREATE FUNCTION command is defined in the SQL standard. The
488 PostgreSQL version is similar but not fully compatible. The attributes
489 are not portable, neither are the different available languages.
490
491 For compatibility with some other database systems, argmode can be
492 written either before or after argname. But only the first way is
493 standard-compliant.
494
495 For parameter defaults, the SQL standard specifies only the syntax with
496 the DEFAULT key word. The syntax with = is used in T-SQL and Firebird.
497
499 ALTER FUNCTION (ALTER_FUNCTION(7)), DROP FUNCTION (DROP_FUNCTION(7)),
500 GRANT(7), LOAD(7), REVOKE(7)
501
502
503
504PostgreSQL 12.6 2021 CREATE FUNCTION(7)