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