|
|
|
|
NameCREATE FUNCTION -- Defines a new function within the database.
Synopsis
CREATE FUNCTION
name
( [
argtype
[, ...] ] )
RETURNS
returntype
AS '
definition
'
LANGUAGE '
langname
'
[ WITH (
attribute
[, ...] ) ]
CREATE FUNCTION
name
( [
argtype
[, ...] ] )
RETURNS
returntype
AS '
obj_file
' [, '
link_symbol
' ]
LANGUAGE '
langname
'
[ WITH (
attribute
[, ...] ) ]
Parameters
-
name
-
The name of the new function being created.
-
argtype
-
The data type of the argument, or arguments, to be accepted by the new function. There are three general input types you may use: base types, complex types, or the special opaque type. The opaque type explicitly allows the function to accept arguments of invalid SQL types. The opaque type is generally used by internal functions, or functions written in internal language such as C, or PL/pgSQL, where the return type is not provided as a standard SQL data type.
-
returntype
-
The data type of the value or values returned by the new function. This may be set as a base type, complex type, setof type (a normal data type, prefixed by setof), or the opaque type.
Using the setof modifier determines that the function will return multiple rows worth of data (by default, a function returns only one row). For example, a return type defined as setof integer creates a function that can return more than a single row of integer values.
-
attribute
-
An optional function attribute. Valid attributes, as of PostgreSQL 7.1.x, are
isstrict and iscacheable.
-
definition
-
The definition of the function to create. This is entered as a string, bound by quotes, though its contents vary widely between languages. The exact content of this string may be an internal function name, a SQL statement, or procedural code in a language such as PL/pgSQL.
-
obj_file
[,
link_symbol
]
-
The file that contains the dynamically loadable object code, and the function name in the C source. The
link_symbol
is only required if the source C function has a name that is different from the intended SQL function name.
-
langname
-
The name of the language the new function is written in. Possible values for this parameter are
C
,
SQL
,
internal
, or the name of a procedural language created using the CREATE LANGUAGE command (e.g.,
plpgsql
). See CREATE LANGUAGE" for further details.
Results
-
CREATE
-
The message returned when a function is created successfully.
Description
Use the CREATE FUNCTION command to create a new function in the connected database. Ownership of the function is set to the PostgreSQL user that created it.
Function attributes
-
iscachable
-
The iscacheable attribute specifies that the function will always return the same result when passed the same argument values (i.e., calculated results are cached). Such a function does not perform a database lookup or use information not directly present in the parameter list. This option is used by the optimizer to determine whether it is safe to pre-evaluate the result of a function call based on past calls, rather than re-executing the function on cached values for previously passed arguments.
-
isstrict
-
The isstrict attribute specifies that the function is strict in its handling of NULL values. This means that whenever the function is passed a NULL argument, it will not operate, and will simply return a NULL value.
Function overloading
PostgreSQL allows
function overloading
. Users of object-oriented programming languages may be
familiar with this term. In PostgreSQL, the term means to create multiple functions with the same name, provided each of
them has a unique set of argument types.
Overloading is useful for creating what seems to be a single function that can handle a large variety of different
input types; to the user, the series of functions you have created become a single, seamless, versatile tool.
Differing from PostgreSQL's ability to overload functions based on argument types, two compiled C functions in one
object file are unable to share the same name. To avoid this problem, you can arbitrarily rename the second C function
that you wish to overload within PostgreSQL to a unique function name in your C source, compile the object code, and then
explicitly define the
link_symbol
parameter as that arbitrary name when creating the overloaded
C function.
Examples
The following example creates a simple SQL function that returns a book title based on the ID number passed to the function:
booktown=#
CREATE FUNCTION title(integer) RETURNS text
booktown-#
AS 'SELECT title from books where id = $1'
booktown-#
LANGUAGE 'sql';
CREATE
The title() function can now be used within the booktown database to retrieve rows with ID numbers matching the number passed as an argument:
booktown=#
SELECT title(41472) AS book_title;
book_title
----------------------
Practical PostgreSQL
(1 row)
|
|
|