PL/Perl - Perl Procedural LanguagePL/PerlPerl
PL/Perl is a loadable procedural language
that enables the Perl programming
language to be used to write
PostgreSQL functions.
Overview
Normally, PL/Perl is installed as a trusted> programming
language named plperl>. In this setup, certain Perl
operations are disabled to preserve security. In general, the operations
that are restricted are those that interact with the environment. This
includes file handle operations, require, and
use (for external modules).
There is no way to access internals of the
database backend or to gain OS-level access under the permissions of the
PostgreSQL user ID, as a C function can do.
Thus, any unprivileged database user may be
permitted to use this language.
Sometimes it is desirable to write Perl functions that are not restricted
--- for example, one might want a Perl function that sends
mail. To handle these cases, PL/Perl can also be installed as an
untrusted> language (usually named plperlu>).
In this case the full Perl language is available. The writer of a PL/PerlU
function must take care that the function cannot be used to do anything
unwanted, since it will be able to do anything that could be done by
a user logged in as the database administrator. Note that the database
system allows only database superusers to create functions in untrusted
languages.
Building and Installing PL/Perl
If the option was supplied to the
configureconfigure script,
the PostgreSQL build process will attempt to
build the PL/Perl shared library and install it in the
PostgreSQL library directory.
On most platforms, since PL/Perl is a shared library, the
libperllibperl library must be a shared library also.
At the time of this writing, this is almost never the case in prebuilt
Perl packages. If this difficulty arises in your situation, a
message like this will appear during the build to point out this
fact:
*** Cannot build PL/Perl because libperl is not a shared library.
*** You might have to rebuild your Perl installation. Refer to
*** the documentation for details.
If you see this, you will have to re-build and install
Perl manually to be able to build
PL/Perl. During the configuration process for
Perl, request a shared library.
After having reinstalled Perl, change to the directory
src/pl/plperl in the
PostgreSQL source tree and issue the commands
gmake clean
gmake all
gmake install
to complete the build and installation of the PL/Perl shared library.
To install
PL/Perl and/or PL/PerlU in a particular database, use the
createlang script, for example
createlang plperl dbname> or
createlang plperlu dbname>.
If a language is installed into template1>, all subsequently
created databases will have the language installed automatically.
DescriptionPL/Perl Functions and Arguments
To create a function in the PL/Perl language, use the standard syntax
CREATE FUNCTION funcname (argument-types) RETURNS return-type AS '
# PL/Perl function body
' LANGUAGE plperl;
PL/PerlU is the same, except that the language should be specified as
plperlu>.
The body of the function is ordinary Perl code. 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;
If a NULL 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 WITH (isStrict)>
to the function definition to make PostgreSQL
do something more reasonable: if a NULL 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 non-null argument to return the non-null
argument, rather than NULL:
CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS '
my ($a,$b) = @_;
if (! defined $a) {
if (! defined $b) { return undef; }
return $b;
}
if (! defined $b) { return $a; }
if ($a > $b) { return $a; }
return $b;
' LANGUAGE plperl;
As shown above,
to return a NULL from a PL/Perl function, return an undefined
value. This can be done whether the function is strict or not.
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;
There is not currently any support for returning a composite-type
result value.
Because the function body is passed as an SQL string literal to
CREATE FUNCTION, you have to escape single
quotes and backslashes within your Perl source, typically by doubling them
as shown in the above example. Another possible approach is to
avoid writing single quotes by using Perl's extended quoting functions
(q[], qq[],
qw[]).
Here is an example of a function that will not work because file
system operations are not allowed for security reasons:
CREATE FUNCTION badfunc() RETURNS integer AS '
open(TEMP, ">/tmp/badfile");
print TEMP "Gotcha!\n";
return 1;
' LANGUAGE plperl;
The creation of the function will succeed, but executing it will not.
Note that if the same function was created by a superuser using language
plperlu>, execution would succeed.
Data Values in PL/Perl
The argument values supplied to a PL/Perl function's script are simply
the input arguments converted to text form (just as if they had been
displayed by a SELECT statement). Conversely, the return>
command will accept any string that is acceptable input format for
the function's declared return type. So, the PL/Perl programmer can
manipulate data values as if they were just text.
Database Access from PL/Perl
Access to the database itself from your Perl function can be done via
an experimental module DBD::PgSPI
(also available at CPAN
mirror sites). This module makes available a
DBI>-compliant database-handle named
$pg_dbh that can be used to perform queries
with normal DBI> syntax.
PL/Perl itself presently provides only one additional Perl command:
elogelog> level, msg
Emit a log or error message. Possible levels are DEBUG>,
NOTICE>, and ERROR>.
DEBUG> and NOTICE> simply emit the given message
into the postmaster log (and send it to the client too, in the case of
NOTICE>). ERROR> raises an error condition:
further execution of the function is abandoned, and the current
transaction is aborted.
Missing Features
PL/Perl functions cannot call each other directly (because they
are anonymous subroutines inside Perl). There's presently
no way for them to share global variables, either.
PL/Perl cannot currently be used to write trigger functions.
DBD::PgSPI or similar capability should be integrated
into the standard PostgreSQL distribution.