Documentação do PostgreSQL 8.2.0 | ||||
---|---|---|---|---|
Anterior | Início | Capítulo 40. PL/Python - Python Procedural Language | Fim | Próxima |
Functions in PL/Python are declared via the standard CREATE FUNCTION syntax:
CREATE FUNCTION nome_da_função (lista_de_argumentos) RETURNS tipo_retornado AS $$ # PL/Python function body $$ LANGUAGE plpythonu;
The body of a function is simply a Python script. When the function is called, its arguments are passed as elements of the array args[]; named arguments are also passed as ordinary variables to the Python script. The result is returned from the Python code in the usual way, with return or yield (in case of a result-set statement).
For example, a function to return the greater of two integers can be defined as:
CREATE FUNCTION pymax (a integer, b integer) RETURNS integer AS $$ if a > b: return a return b $$ LANGUAGE plpythonu;
The Python code that is given as the body of the function definition is transformed into a Python function. For example, the above results in
def __plpython_procedure_pymax_23456(): if a > b: return a return b
assuming that 23456 is the OID assigned to the function by PostgreSQL.
The PostgreSQL function parameters are available in the global args list. In the pymax example, args[0] contains whatever was passed in as the first argument and args[1] contains the second argument's value. Alternatively, one can use named parameters as shown in the example above. Use of named parameters is usually more readable.
If an SQL null value is passed to a function, the argument value will appear as None in Python. The above function definition will return the wrong answer for null inputs. We could add STRICT to the function definition to make PostgreSQL do something more reasonable: if a null value is passed, the function will not be called at all, but will just return a null result automatically. Alternatively, we could check for null inputs in the function body:
CREATE FUNCTION pymax (a integer, b integer) RETURNS integer AS $$ if (a is None) or (b is None): return None if a > b: return a return b $$ LANGUAGE plpythonu;
As shown above, to return an SQL null value from a PL/Python function, return the value None. This can be done whether the function is strict or not.
Composite-type arguments are passed to the function as Python mappings. The element names of the mapping are the attribute names of the composite type. If an attribute in the passed row has the null value, it has the value None in the mapping. Here is an example:
CREATE TABLE employee ( name text, salary integer, age integer ); CREATE FUNCTION overpaid (e employee) RETURNS boolean AS $$ if e["salary"] > 200000: return True if (e["age"] < 30) and (e["salary"] > 100000): return True return False $$ LANGUAGE plpythonu;
There are multiple ways to return row or composite types from a Python function. The following examples assume we have:
CREATE TYPE named_value AS ( name text, value integer );
A composite result can be returned as a:
Returned sequence objects must have the same number of items as the composite result type has fields. The item with index 0 is assigned to the first field of the composite type, 1 to the second and so on. For example:
CREATE FUNCTION make_pair (name text, value integer) RETURNS named_value AS $$ return [ name, value ] # or alternatively, as tuple: return ( name, value ) $$ LANGUAGE plpythonu;
To return a SQL null for any column, insert None at the corresponding position.
The value for each result type column is retrieved from the mapping with the column name as key. Example:
CREATE FUNCTION make_pair (name text, value integer) RETURNS named_value AS $$ return { "name": name, "value": value } $$ LANGUAGE plpythonu;
Any extra dictionary key/value pairs are ignored. Missing keys are treated as errors. To return a SQL null value for any column, insert None with the corresponding column name as the key.
This works the same as a mapping. Example:
CREATE FUNCTION make_pair (name text, value integer) RETURNS named_value AS $$ class named_value: def __init__ (self, n, v): self.name = n self.value = v return named_value(name, value) # or simply class nv: pass nv.name = name nv.value = value return nv $$ LANGUAGE plpythonu;
If you do not provide a return value, Python returns the default None. PL/Python translates Python's None into the SQL null value.
A PL/Python function can also return sets of scalar or composite types. There are several ways to achieve this because the returned object is internally turned into an iterator. The following examples assume we have composite type:
CREATE TYPE greeting AS ( how text, who text );
A set result can be returned from a:
CREATE FUNCTION greet (how text) RETURNS SETOF greeting AS $$ # return tuple containing lists as composite types # all other combinations work also return ( [ how, "World" ], [ how, "PostgreSQL" ], [ how, "PL/Python" ] ) $$ LANGUAGE plpythonu;
CREATE FUNCTION greet (how text) RETURNS SETOF greeting AS $$ class producer: def __init__ (self, how, who): self.how = how self.who = who self.ndx = -1 def __iter__ (self): return self def next (self): self.ndx += 1 if self.ndx == len(self.who): raise StopIteration return ( self.how, self.who[self.ndx] ) return producer(how, [ "World", "PostgreSQL", "PL/Python" ]) $$ LANGUAGE plpythonu;
CREATE FUNCTION greet (how text) RETURNS SETOF greeting AS $$ for who in [ "World", "PostgreSQL", "PL/Python" ]: yield ( how, who ) $$ LANGUAGE plpythonu;
Atenção |
Currently, due to Python bug #1483133, some debug versions of Python 2.4 (configured and compiled with option --with-pydebug) are known to crash the PostgreSQL server when using an iterator to return a set result. Unpatched versions of Fedora 4 contain this bug. It does not happen in production versions of Python or on patched versions of Fedora 4. |
The global dictionary SD is available to store data between function calls. This variable is private static data. The global dictionary GD is public data, available to all Python functions within a session. Use with care.
Each function gets its own execution environment in the Python interpreter, so that global data and function arguments from myfunc are not available to myfunc2. The exception is the data in the GD dictionary, as mentioned above.