Postgres allows users to add new programming languages to be available for writing functions and procedures. These are called procedural languages (PL). In the case of a function or trigger procedure written in a procedural language, the database server has no built-in knowledge about how to interpret the function's source text. Instead, the task is passed to a special handler that knows the details of the language. The handler could either do all the work of parsing, syntax analysis, execution, etc. itself, or it could serve as "glue" between Postgres and an existing implementation of a programming language. The handler itself is a special programming language function compiled into a shared object and loaded on demand.
Writing a handler for a new procedural language is outside the scope of this manual, although some information is provided in the CREATE LANGUAGE reference page. Several procedural languages are available in the standard Postgres distribution.
A procedural language must be "installed" into each database where it is to be used. But procedural languages installed in the template1 database are automatically available in all subsequently created databases. So the database administrator can decide which languages are available in which databases, and can make some languages available by default if he chooses.
For the languages supplied with the standard distribution, the shell script createlang may be used instead of carrying out the details by hand. For example, to install PL/pgSQL into the template1 database, use
createlang plpgsql template1The manual procedure described below is only recommended for installing custom languages that createlang does not know about.
Manual Procedural Language Installation
A procedural language is installed in the database in three steps, which must be carried out by a database superuser.
The shared object for the language handler must be compiled and installed into an appropriate library directory. This works in the same way as building and installing modules with regular user-defined C functions does; see Section 13.4.6.
The handler must be declared with the command
CREATE FUNCTION handler_function_name () RETURNS OPAQUE AS 'path-to-shared-object' LANGUAGE 'C';The special return type of OPAQUE tells the database that this function does not return one of the defined SQL data types and is not directly usable in SQL statements.
The PL must be declared with the command
CREATE [TRUSTED] [PROCEDURAL] LANGUAGE 'language-name' HANDLER handler_function_name LANCOMPILER 'description';The optional key word TRUSTED tells whether ordinary database users that have no superuser privileges should be allowed to use this language to create functions and trigger procedures. Since PL functions are executed inside the database backend, the TRUSTED flag should only be given for languages that do not allow access to database backends internals or the filesystem. The languages PL/pgSQL, PL/Tcl, and PL/Perl are known to be trusted; the language PL/TclU should not be marked trusted.
In a default Postgres installation, the handler for the PL/pgSQL language is built and installed into the "library" directory. If Tcl/Tk support is configured in, the handlers for PL/Tcl and PL/TclU are also built and installed in the same location. Likewise, the PL/Perl handler is built and installed if Perl support is configured. The createlang script automates the two CREATE steps described above.
Example
The following command tells the database where to find the shared object for the PL/pgSQL language's call handler function.
CREATE FUNCTION plpgsql_call_handler () RETURNS OPAQUE AS '/usr/local/pgsql/lib/plpgsql.so' LANGUAGE 'C';
The command
CREATE TRUSTED PROCEDURAL LANGUAGE 'plpgsql' HANDLER plpgsql_call_handler LANCOMPILER 'PL/pgSQL';then defines that the previously declared call handler function should be invoked for functions and trigger procedures where the language attribute is 'plpgsql'.