Postgres-XC 1.0.4 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Chapter 40. PL/Perl - Perl Procedural Language | Fast Forward | Next |
Note: The following description applies both to Postgres-XC and PostgreSQL if not described explicitly.
To create a function in the PL/Perl language, use the standard CREATE FUNCTION syntax:
CREATE FUNCTION funcname (argument-types) RETURNS return-type AS $$ # PL/Perl function body $$ LANGUAGE plperl;
The body of the function is ordinary Perl code. In fact, the PL/Perl glue code wraps it inside a Perl subroutine. A PL/Perl function is called in a scalar context, so it can't return a list. You can return non-scalar values (arrays, records, and sets) by returning a reference, as discussed below.
PL/Perl also supports anonymous code blocks called with the DO statement:
DO $$ # PL/Perl code $$ LANGUAGE plperl;
An anonymous code block receives no arguments, and whatever value it might return is discarded. Otherwise it behaves just like a function.
Note: The use of named nested subroutines is dangerous in Perl, especially if they refer to lexical variables in the enclosing scope. Because a PL/Perl function is wrapped in a subroutine, any named subroutine you place inside one will be nested. In general, it is far safer to create anonymous subroutines which you call via a coderef. For more information, see the entries for Variable "%s" will not stay shared and Variable "%s" is not available in the perldiag man page, or search the Internet for "perl nested named subroutine".
The syntax of the CREATE FUNCTION command requires the function body to be written as a string constant. It is usually most convenient to use dollar quoting (see Section 4.1.2.4) for the string constant. If you choose to use escape string syntax E'', you must double any single quote marks (') and backslashes (\) used in the body of the function (see Section 4.1.2.1).
Arguments and results are handled as in any other Perl subroutine: arguments are passed in @_, and a result value is returned with return or as the last expression evaluated in the function.
For example, a function returning the greater of two integer values could be defined as:
CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS $$ if ($_[0] > $_[1]) { return $_[0]; } return $_[1]; $$ LANGUAGE plperl;
Note: Arguments will be converted from the database's encoding to UTF-8 for use inside PL/Perl, and then converted from UTF-8 back to the database encoding upon return.
If an SQL null value is passed to a function,
the argument value will appear as "undefined" in Perl. The
above function definition will not behave very nicely with null
inputs (in fact, it will act as though they are zeroes). 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 undefined inputs in the function body. For
example, suppose that we wanted perl_max
with
one null and one nonnull argument to return the nonnull argument,
rather than a null value:
CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS $$ my ($x, $y) = @_; if (not defined $x) { return undef if not defined $y; return $y; } return $x if not defined $y; return $x if $x > $y; return $y; $$ LANGUAGE plperl;
As shown above, to return an SQL null value from a PL/Perl function, return an undefined value. This can be done whether the function is strict or not.
Anything in a function argument that is not a reference is
a string, which is in the standard PostgreSQL
external text representation for the relevant data type. In the case of
ordinary numeric or text types, Perl will just do the right thing and
the programmer will normally not have to worry about it. However, in
other cases the argument will need to be converted into a form that is
more usable in Perl. For example, the decode_bytea
function can be used to convert an argument of
type bytea into unescaped binary.
Similarly, values passed back to PostgreSQL
must be in the external text representation format. For example, the
encode_bytea
function can be used to
escape binary data for a return value of type bytea.
Perl can return PostgreSQL arrays as references to Perl arrays. Here is an example:
CREATE OR REPLACE function returns_array() RETURNS text[][] AS $$ return [['a"b','c,d'],['e\\f','g']]; $$ LANGUAGE plperl; select returns_array();
Perl passes PostgreSQL arrays as a blessed PostgreSQL::InServer::ARRAY object. This object may be treated as an array reference or a string, allowing for backward compatibility with Perl code written for PostgreSQL versions below 9.1 to run. For example:
CREATE OR REPLACE FUNCTION concat_array_elements(text[]) RETURNS TEXT AS $$ my $arg = shift; my $result = ""; return undef if (!defined $arg); # as an array reference for (@$arg) { $result .= $_; } # also works as a string $result .= $arg; return $result; $$ LANGUAGE plperl; SELECT concat_array_elements(ARRAY['PL','/','Perl']);
Note: Multi-dimensional arrays are represented as references to lower-dimensional arrays of references in a way common to every Perl programmer.
Composite-type arguments are passed to the function as references to hashes. The keys of the hash are the attribute names of the composite type. Here is an example:
CREATE TABLE employee ( name text, basesalary integer, bonus integer ); CREATE FUNCTION empcomp(employee) RETURNS integer AS $$ my ($emp) = @_; return $emp->{basesalary} + $emp->{bonus}; $$ LANGUAGE plperl; SELECT name, empcomp(employee.*) FROM employee;
A PL/Perl function can return a composite-type result using the same approach: return a reference to a hash that has the required attributes. For example:
CREATE TYPE testrowperl AS (f1 integer, f2 text, f3 text); CREATE OR REPLACE FUNCTION perl_row() RETURNS testrowperl AS $$ return {f2 => 'hello', f1 => 1, f3 => 'world'}; $$ LANGUAGE plperl; SELECT * FROM perl_row();
Any columns in the declared result data type that are not present in the hash will be returned as null values.
PL/Perl functions can also return sets of either scalar or
composite types. Usually you'll want to return rows one at a
time, both to speed up startup time and to keep from queueing up
the entire result set in memory. You can do this with
return_next
as illustrated below. Note that
after the last return_next
, you must put
either return or (better) return
undef.
CREATE OR REPLACE FUNCTION perl_set_int(int) RETURNS SETOF INTEGER AS $$ foreach (0..$_[0]) { return_next($_); } return undef; $$ LANGUAGE plperl; SELECT * FROM perl_set_int(5); CREATE OR REPLACE FUNCTION perl_set() RETURNS SETOF testrowperl AS $$ return_next({ f1 => 1, f2 => 'Hello', f3 => 'World' }); return_next({ f1 => 2, f2 => 'Hello', f3 => 'PostgreSQL' }); return_next({ f1 => 3, f2 => 'Hello', f3 => 'PL/Perl' }); return undef; $$ LANGUAGE plperl;
For small result sets, you can return a reference to an array that contains either scalars, references to arrays, or references to hashes for simple types, array types, and composite types, respectively. Here are some simple examples of returning the entire result set as an array reference:
CREATE OR REPLACE FUNCTION perl_set_int(int) RETURNS SETOF INTEGER AS $$ return [0..$_[0]]; $$ LANGUAGE plperl; SELECT * FROM perl_set_int(5); CREATE OR REPLACE FUNCTION perl_set() RETURNS SETOF testrowperl AS $$ return [ { f1 => 1, f2 => 'Hello', f3 => 'World' }, { f1 => 2, f2 => 'Hello', f3 => 'PostgreSQL' }, { f1 => 3, f2 => 'Hello', f3 => 'PL/Perl' } ]; $$ LANGUAGE plperl; SELECT * FROM perl_set();
If you wish to use the strict pragma with your code you have a few options. For temporary global use you can SET plperl.use_strict to true. This will affect subsequent compilations of PL/Perl functions, but not functions already compiled in the current session. For permanent global use you can set plperl.use_strict to true in the postgresql.conf file.
For permanent use in specific functions you can simply put:
use strict;
at the top of the function body.
The feature pragma is also available to use
if your Perl is version 5.10.0 or higher.