1CREATE FUNCTION(7) PostgreSQL 13.4 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 }
17 | [ NOT ] LEAKPROOF
18 | { CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT }
19 | { [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER }
20 | PARALLEL { UNSAFE | RESTRICTED | SAFE }
21 | COST execution_cost
22 | ROWS result_rows
23 | SUPPORT support_function
24 | SET configuration_parameter { TO value | = value | FROM CURRENT }
25 | AS 'definition'
26 | AS 'obj_file', 'link_symbol'
27 } ...
28
30 CREATE FUNCTION defines a new function. CREATE OR REPLACE FUNCTION
31 will either create a new function, or replace an existing definition.
32 To be able to define a function, the user must have the USAGE privilege
33 on the language.
34
35 If a schema name is included, then the function is created in the
36 specified schema. Otherwise it is created in the current schema. The
37 name of the new function must not match any existing function or
38 procedure with the same input argument types in the same schema.
39 However, functions and procedures of different argument types can share
40 a name (this is called overloading).
41
42 To replace the current definition of an existing function, use CREATE
43 OR REPLACE FUNCTION. It is not possible to change the name or argument
44 types of a function this way (if you tried, you would actually be
45 creating a new, distinct function). Also, CREATE OR REPLACE FUNCTION
46 will not let you change the return type of an existing function. To do
47 that, you must drop and recreate the function. (When using OUT
48 parameters, that means you cannot change the types of any OUT
49 parameters except by dropping the function.)
50
51 When CREATE OR REPLACE FUNCTION is used to replace an existing
52 function, the ownership and permissions of the function do not change.
53 All other function properties are assigned the values specified or
54 implied in the command. You must own the function to replace it (this
55 includes being a member of the owning role).
56
57 If you drop and then recreate a function, the new function is not the
58 same entity as the old; you will have to drop existing rules, views,
59 triggers, etc. that refer to the old function. Use CREATE OR REPLACE
60 FUNCTION to change a function definition without breaking objects that
61 refer to the function. Also, ALTER FUNCTION can be used to change most
62 of the auxiliary properties of an existing function.
63
64 The user that creates the function becomes the owner of the function.
65
66 To be able to create a function, you must have USAGE privilege on the
67 argument types and the return type.
68
69 Refer to Section 37.3 for further information on writing functions.
70
72 name
73 The name (optionally schema-qualified) of the function to create.
74
75 argmode
76 The mode of an argument: IN, OUT, INOUT, or VARIADIC. If omitted,
77 the default is IN. Only OUT arguments can follow a VARIADIC one.
78 Also, OUT and INOUT arguments cannot be used together with the
79 RETURNS TABLE notation.
80
81 argname
82 The name of an argument. Some languages (including SQL and
83 PL/pgSQL) let you use the name in the function body. For other
84 languages the name of an input argument is just extra
85 documentation, so far as the function itself is concerned; but you
86 can use input argument names when calling a function to improve
87 readability (see Section 4.3). In any case, the name of an output
88 argument is significant, because it defines the column name in the
89 result row type. (If you omit the name for an output argument, the
90 system will choose a default column name.)
91
92 argtype
93 The data type(s) of the function's arguments (optionally
94 schema-qualified), if any. The argument types can be base,
95 composite, or domain types, or can reference the type of a table
96 column.
97
98 Depending on the implementation language it might also be allowed
99 to specify “pseudo-types” such as cstring. Pseudo-types indicate
100 that the actual argument type is either incompletely specified, or
101 outside the set of ordinary SQL data types.
102
103 The type of a column is referenced by writing
104 table_name.column_name%TYPE. Using this feature can sometimes help
105 make a function independent of changes to the definition of a
106 table.
107
108 default_expr
109 An expression to be used as default value if the parameter is not
110 specified. The expression has to be coercible to the argument type
111 of the parameter. Only input (including INOUT) parameters can have
112 a default value. All input parameters following a parameter with a
113 default value must have default values as well.
114
115 rettype
116 The return data type (optionally schema-qualified). The return type
117 can be a base, composite, or domain type, or can reference the type
118 of a table column. Depending on the implementation language it
119 might also be allowed to specify “pseudo-types” such as cstring. If
120 the function is not supposed to return a value, specify void as the
121 return type.
122
123 When there are OUT or INOUT parameters, the RETURNS clause can be
124 omitted. If present, it must agree with the result type implied by
125 the output parameters: RECORD if there are multiple output
126 parameters, or the same type as the single output parameter.
127
128 The SETOF modifier indicates that the function will return a set of
129 items, rather than a single item.
130
131 The type of a column is referenced by writing
132 table_name.column_name%TYPE.
133
134 column_name
135 The name of an output column in the RETURNS TABLE syntax. This is
136 effectively another way of declaring a named OUT parameter, except
137 that RETURNS TABLE also implies RETURNS SETOF.
138
139 column_type
140 The data type of an output column in the RETURNS TABLE syntax.
141
142 lang_name
143 The name of the language that the function is implemented in. It
144 can be sql, c, internal, or the name of a user-defined procedural
145 language, e.g., plpgsql. Enclosing the name in single quotes is
146 deprecated and requires matching case.
147
148 TRANSFORM { FOR TYPE type_name } [, ... ] }
149 Lists which transforms a call to the function should apply.
150 Transforms convert between SQL types and language-specific data
151 types; see CREATE TRANSFORM (CREATE_TRANSFORM(7)). Procedural
152 language implementations usually have hardcoded knowledge of the
153 built-in types, so those don't need to be listed here. If a
154 procedural language implementation does not know how to handle a
155 type and no transform is supplied, it will fall back to a default
156 behavior for converting data types, but this depends on the
157 implementation.
158
159 WINDOW
160 WINDOW indicates that the function is a window function rather than
161 a plain function. This is currently only useful for functions
162 written in C. The WINDOW attribute cannot be changed when replacing
163 an existing function definition.
164
165 IMMUTABLE
166 STABLE
167 VOLATILE
168 These attributes inform the query optimizer about the behavior of
169 the function. At most one choice can be specified. If none of these
170 appear, VOLATILE is the default assumption.
171
172 IMMUTABLE indicates that the function cannot modify the database
173 and always returns the same result when given the same argument
174 values; that is, it does not do database lookups or otherwise use
175 information not directly present in its argument list. If this
176 option is given, any call of the function with all-constant
177 arguments can be immediately replaced with the function value.
178
179 STABLE indicates that the function cannot modify the database, and
180 that within a single table scan it will consistently return the
181 same result for the same argument values, but that its result could
182 change across SQL statements. This is the appropriate selection for
183 functions whose results depend on database lookups, parameter
184 variables (such as the current time zone), etc. (It is
185 inappropriate for AFTER triggers that wish to query rows modified
186 by the current command.) Also note that the current_timestamp
187 family of functions qualify as stable, since their values do not
188 change within a transaction.
189
190 VOLATILE indicates that the function value can change even within a
191 single table scan, so no optimizations can be made. Relatively few
192 database functions are volatile in this sense; some examples are
193 random(), currval(), timeofday(). But note that any function that
194 has side-effects must be classified volatile, even if its result is
195 quite predictable, to prevent calls from being optimized away; an
196 example is setval().
197
198 For additional details see Section 37.7.
199
200 LEAKPROOF
201 LEAKPROOF indicates that the function has no side effects. It
202 reveals no information about its arguments other than by its return
203 value. For example, a function which throws an error message for
204 some argument values but not others, or which includes the argument
205 values in any error message, is not leakproof. This affects how the
206 system executes queries against views created with the
207 security_barrier option or tables with row level security enabled.
208 The system will enforce conditions from security policies and
209 security barrier views before any user-supplied conditions from the
210 query itself that contain non-leakproof functions, in order to
211 prevent the inadvertent exposure of data. Functions and operators
212 marked as leakproof are assumed to be trustworthy, and may be
213 executed before conditions from security policies and security
214 barrier views. In addition, functions which do not take arguments
215 or which are not passed any arguments from the security barrier
216 view or table do not have to be marked as leakproof to be executed
217 before security conditions. See CREATE VIEW (CREATE_VIEW(7)) and
218 Section 40.5. This option can only be set by the superuser.
219
220 CALLED ON NULL INPUT
221 RETURNS NULL ON NULL INPUT
222 STRICT
223 CALLED ON NULL INPUT (the default) indicates that the function will
224 be called normally when some of its arguments are null. It is then
225 the function author's responsibility to check for null values if
226 necessary and respond appropriately.
227
228 RETURNS NULL ON NULL INPUT or STRICT indicates that the function
229 always returns null whenever any of its arguments are null. If this
230 parameter is specified, the function is not executed when there are
231 null arguments; instead a null result is assumed automatically.
232
233 [EXTERNAL] SECURITY INVOKER
234 [EXTERNAL] SECURITY DEFINER
235 SECURITY INVOKER indicates that the function is to be executed with
236 the privileges of the user that calls it. That is the default.
237 SECURITY DEFINER specifies that the function is to be executed with
238 the privileges of the user that owns it.
239
240 The key word EXTERNAL is allowed for SQL conformance, but it is
241 optional since, unlike in SQL, this feature applies to all
242 functions not only external ones.
243
244 PARALLEL
245 PARALLEL UNSAFE indicates that the function can't be executed in
246 parallel mode and the presence of such a function in an SQL
247 statement forces a serial execution plan. This is the default.
248 PARALLEL RESTRICTED indicates that the function can be executed in
249 parallel mode, but the execution is restricted to parallel group
250 leader. PARALLEL SAFE indicates that the function is safe to run
251 in parallel mode without restriction.
252
253 Functions should be labeled parallel unsafe if they modify any
254 database state, or if they make changes to the transaction such as
255 using sub-transactions, or if they access sequences or attempt to
256 make persistent changes to settings (e.g., setval). They should be
257 labeled as parallel restricted if they access temporary tables,
258 client connection state, cursors, prepared statements, or
259 miscellaneous backend-local state which the system cannot
260 synchronize in parallel mode (e.g., setseed cannot be executed
261 other than by the group leader because a change made by another
262 process would not be reflected in the leader). In general, if a
263 function is labeled as being safe when it is restricted or unsafe,
264 or if it is labeled as being restricted when it is in fact unsafe,
265 it may throw errors or produce wrong answers when used in a
266 parallel query. C-language functions could in theory exhibit
267 totally undefined behavior if mislabeled, since there is no way for
268 the system to protect itself against arbitrary C code, but in most
269 likely cases the result will be no worse than for any other
270 function. If in doubt, functions should be labeled as UNSAFE, which
271 is the default.
272
273 COST execution_cost
274 A positive number giving the estimated execution cost for the
275 function, in units of cpu_operator_cost. If the function returns a
276 set, this is the cost per returned row. If the cost is not
277 specified, 1 unit is assumed for C-language and internal functions,
278 and 100 units for functions in all other languages. Larger values
279 cause the planner to try to avoid evaluating the function more
280 often than necessary.
281
282 ROWS result_rows
283 A positive number giving the estimated number of rows that the
284 planner should expect the function to return. This is only allowed
285 when the function is declared to return a set. The default
286 assumption is 1000 rows.
287
288 SUPPORT support_function
289 The name (optionally schema-qualified) of a planner support
290 function to use for this function. See Section 37.11 for details.
291 You must be superuser to use this option.
292
293 configuration_parameter
294 value
295 The SET clause causes the specified configuration parameter to be
296 set to the specified value when the function is entered, and then
297 restored to its prior value when the function exits. SET FROM
298 CURRENT saves the value of the parameter that is current when
299 CREATE FUNCTION is executed as the value to be applied when the
300 function is entered.
301
302 If a SET clause is attached to a function, then the effects of a
303 SET LOCAL command executed inside the function for the same
304 variable are restricted to the function: the configuration
305 parameter's prior value is still restored at function exit.
306 However, an ordinary SET command (without LOCAL) overrides the SET
307 clause, much as it would do for a previous SET LOCAL command: the
308 effects of such a command will persist after function exit, unless
309 the current transaction is rolled back.
310
311 See SET(7) and Chapter 19 for more information about allowed
312 parameter names and values.
313
314 definition
315 A string constant defining the function; the meaning depends on the
316 language. It can be an internal function name, the path to an
317 object file, an SQL command, or text in a procedural language.
318
319 It is often helpful to use dollar quoting (see Section 4.1.2.4) to
320 write the function definition string, rather than the normal single
321 quote syntax. Without dollar quoting, any single quotes or
322 backslashes in the function definition must be escaped by doubling
323 them.
324
325 obj_file, link_symbol
326 This form of the AS clause is used for dynamically loadable C
327 language functions when the function name in the C language source
328 code is not the same as the name of the SQL function. The string
329 obj_file is the name of the shared library file containing the
330 compiled C function, and is interpreted as for the LOAD(7) command.
331 The string link_symbol is the function's link symbol, that is, the
332 name of the function in the C language source code. If the link
333 symbol is omitted, it is assumed to be the same as the name of the
334 SQL function being defined. The C names of all functions must be
335 different, so you must give overloaded C functions different C
336 names (for example, use the argument types as part of the C names).
337
338 When repeated CREATE FUNCTION calls refer to the same object file,
339 the file is only loaded once per session. To unload and reload the
340 file (perhaps during development), start a new session.
341
343 PostgreSQL allows function overloading; that is, the same name can be
344 used for several different functions so long as they have distinct
345 input argument types. Whether or not you use it, this capability
346 entails security precautions when calling functions in databases where
347 some users mistrust other users; see Section 10.3.
348
349 Two functions are considered the same if they have the same names and
350 input argument types, ignoring any OUT parameters. Thus for example
351 these declarations conflict:
352
353 CREATE FUNCTION foo(int) ...
354 CREATE FUNCTION foo(int, out text) ...
355
356 Functions that have different argument type lists will not be
357 considered to conflict at creation time, but if defaults are provided
358 they might conflict in use. For example, consider
359
360 CREATE FUNCTION foo(int) ...
361 CREATE FUNCTION foo(int, int default 42) ...
362
363 A call foo(10) will fail due to the ambiguity about which function
364 should be called.
365
367 The full SQL type syntax is allowed for declaring a function's
368 arguments and return value. However, parenthesized type modifiers
369 (e.g., the precision field for type numeric) are discarded by CREATE
370 FUNCTION. Thus for example CREATE FUNCTION foo (varchar(10)) ... is
371 exactly the same as CREATE FUNCTION foo (varchar) ....
372
373 When replacing an existing function with CREATE OR REPLACE FUNCTION,
374 there are restrictions on changing parameter names. You cannot change
375 the name already assigned to any input parameter (although you can add
376 names to parameters that had none before). If there is more than one
377 output parameter, you cannot change the names of the output parameters,
378 because that would change the column names of the anonymous composite
379 type that describes the function's result. These restrictions are made
380 to ensure that existing calls of the function do not stop working when
381 it is replaced.
382
383 If a function is declared STRICT with a VARIADIC argument, the
384 strictness check tests that the variadic array as a whole is non-null.
385 The function will still be called if the array has null elements.
386
388 Add two integers using a SQL function:
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 13.4 2021 CREATE FUNCTION(7)