PL/Java 1.2 User Guide

Java™ is a registered trademark of Sun Microsystems, Inc. in the United States and other countries.

Table of contents

Utilities
   Deployer
 SQLJ functions
    install_jar
    replace_jar
    remove_jar
    get_classpath
    set_classpath
Writing Java functions
    Type mapping
    Returning complex types
    Functions returning sets
    Using JDBC
    Exception handling
    Savepoints
    Logging
Security
    Installation
    Trusted language
    Execution of the deployment descriptor
    Classpath manipulation
Module Configuration

Utilities

Deployer

When running the deployer, you must use a classpath that can see the deploy.jar found in the PL/Java distribution and the postgresql.jar from the PostgreSQL distribution. The former contains the code for the deployer command and the second includes the PostgreSQL JDBC driver. You then run the deployer with the command:

java -cp <your classpath> org.postgresql.pljava.deploy.Deployer [ options ]

It's recommended that create a shell script or a .bat script that does this for you so that you don't have to do this over and over again.

Deployer options

-install Installs the Java™ language along with the sqlj procedures. The deployer will fail if the language is installed already.
-reinstall Reinstalls the Java™ language and the sqlj procedures. This will effectively drop all jar files that have been loaded.
-remove Drops the Java™ language and the sqlj procedures and loaded jars.
-user <user name> Name of user that connects to the database. Default is the current user.
-password <password> Password of user that connects to the database. Default is no password.
-database <database> The name of the database to connect to. Default is to use the user name.
-host <host name> Name of the host. Default is "localhost".
-port <port number> Port number. Default is blank.
-cygwin Use this option if the host runs on a Cygwin based windows platform. Affects the name used for the PL/Java dynamic library.

NOTE This option should not be used when running native the Win32 port.

 

Deploying using SQL

An alternative to using the deployer is to run the install.sql and uninstall.sql scripts that are included in the distribution.

SQLJ functions

Deployment descriptor

The install_jar, replace_jar, and remove_jar can act on a deployment descriptor allowing SQL commands to be executed after the jar has been installed or prior to removal. The format of the deployment descriptor is stipulated by ISO/IEC 9075-13:2003.

The descriptor is added as a normal text file to your jar file. In the Manifest of the jar there must be an entry that appoints the file as the SQLJ deployment descriptor.

Name: <deployment descriptor entry in the jar>SQLJDeploymentDescriptor: TRUE

The deployment descriptor must have the following form:

<descriptor file> ::=
SQLActions <left bracket> <rightbracket> <equal sign>
{ [ <double quote> <action group> <double quote>
  [ <comma> <double quote> <action group> <double quote> ] ] }
<action group> ::=
    <install actions>
  | <remove actions>
<install actions> ::=
  BEGIN INSTALL [ <command> <semicolon> ]... END INSTALL
<remove actions> ::=
  BEGIN REMOVE [ <command> <semicolon> ]... END REMOVE
<command> ::=
    <SQL statement>
  | <implementor block>
<SQL statement> ::= !! <SQL token>...
<implementor block> ::=
  BEGIN <implementor name> <SQL token>... END <implementor name>
<implementor name> ::= <identifier>
<SQL token> ::= !! an SQL lexical unit specified by the term "<token>" in Sub clause 5.2, "<token> and <separator>", in ISO/IEC 9075-2.

If implementor blocks are used, PL/Java will consider only those with implementor name PostgreSQL (case insensitive). Here is a small sample of a deployment descriptor:

SQLActions[] = {
  "BEGIN INSTALL
    CREATE FUNCTION javatest.java_getTimestamp()
      RETURNS timestamp
      AS 'org.postgresql.pljava.example.Parameters.getTimestamp'
      LANGUAGE java;
      END INSTALL",
  "BEGIN REMOVE
    DROP FUNCTION javatest.java_getTimestamp();
  END REMOVE"
}

install_jar

The install_jar command loads a jarfile from a location appointed by an URL into the SQLJ jar repository. It is an error if a jar with the given name already exists in the repository.

Usage

SELECT sqlj.install_jar(<jar_url>, <jar_name>, <deploy>);

Parameters

jar_url The URL that denotes the location of the jar that should be loaded.
jar_name This is the name by which this jar can be referenced once it has been loaded.
deploy True if the jar should be deployed according to a deployment descriptor, false otherwise.

replace_jar

The replace_jar will replace a loaded jar with another jar. Use this command to update already loaded files. It's an error if the jar is not found.

Usage

SELECT sqlj.replace_jar(<jar_url>, <jar_name>, <redeploy>);

Parameters

jar_url The URL that denotes the location of the jar that should be loaded.
jar_name The name of the jar to be replaced.
redeploy True if the jar should be undeployed according to the deployment descriptor of the old jar and deployed according to the deployment descriptor of the new jar, false otherwise.

remove_jar

The remove_jar will drop the jar from the jar repository. Any classpath that references this jar will be updated accordingly. It's an error if the jar is not found.

Usage

SELECT sqlj.remove_jar(<jar_name>, <undeploy>);

Parameters

jar_name The name of the jar to be removed.
undeploy True if the jar should be undeployed according to a deployment descriptor, false otherwise.

get_classpath

The get_classpath will return the classpath that has been defined for the given schema or NULL if the schema has no classpath. It's an error if the given schema does not exist.

Usage

SELECT sqlj.get_classpath(<schema>);

Parameters

schema The name of the schema.

set_classpath

The set_classpath will define a classpath for the given schema. A classpath consists of a colon separated list of jar names. It's an error if the given schema does not exist or if one or more jar names references non existent jars.

Usage

SELECT sqlj.set_classpath(<schema>, <classpath>);

Parameters

schema The name of the schema.
classpath The colon separated list of jar names.

Writing Java functions

SQL declaration

A Java function is declared with the name of a class and a static method on that class. The class will be resolved using the classpath that has been defined for the schema where the function is declared. If no classpath has been defined for that schema, the "public" schema is used. If no classpath is found there either, the class is resolved using the system classloader.

The following function can be declared to access the static method getProperty on java.lang.System class:

CREATE FUNCTION getsysprop(VARCHAR)
  RETURNS VARCHAR
  AS 'java.lang.System.getProperty'
  LANGUAGE java;
SELECT getsysprop('user.home');

Type mapping

Scalar types are mapped in a straight forward way. Here's a table of the current mappings (will be updated as more mappings are implemented).

PostgreSQL Java
bool boolean
'char' byte
int2 short
int4 int
int8 long
float4 float
float8 double
varchar java.lang.String
text java.lang.String
bytea byte[]
date java.sql.Date
time java.sql.Time (stored value treated as local time)
timetz java.sql.Time
timestamp java.sql.Timestamp (stored value treated as local time)
timestamptz java.sql.Timestamp
complex java.sql.ResultSet
setof complex java.sql.ResultSet

All other types are currently mapped to java.lang.String and will utilize the standard textin/textout routines registered for respective type.

NULL handling

The scalar types that map to Java primitives can not be passed as null values. To enable this, those types can have an alternative mapping. You enable this mapping by explicitly denoting it in the method reference.

CREATE FUNCTION trueIfEvenOrNull(integer)
  RETURNS bool
  AS 'foo.fee.Fum.trueIfEvenOrNull(java.lang.Integer)'
  LANGUAGE java;

In java, you would have something like:

package foo.fee;
public class Fum
{
  static boolean trueIfEvenOrNull(Integer value)
  {
    return (value == null)
      ? true
      : (value.intValue() % 1) == 0;
  }
}

The following two statements should both yield true:

SELECT trueIfEvenOrNull(NULL);
SELECT trueIfEvenOrNull(4);

In order to return null values from a Java method, you simply use the object type that corresponds to the primitive (i.e. you return java.lang.Integer instead of int). The PL/Java resolve mechanism will find the method regardless. Since Java cannot have different return types for methods with the same name, this does not introduce any ambiguity.

Complex types

A complex type will always be passed as a read-only java.sql.ResultSet with exaclty one row. The ResultSet will be positioned on its row so no call to next should be made. The values of the complex type are retrieved using the standard getter methods of the ResultSet.

Example:

CREATE TYPE complexTest
  AS(base integer, incbase integer, ctime timestamptz);

CREATE FUNCTION useComplexTest(complexTest)
  RETURNS VARCHAR
  AS 'foo.fee.Fum.useComplexTest'
  IMMUTABLE LANGUAGE java;

In class Fum we add the static following static method:

public static String useComplexTest(ResultSet complexTest)
throws SQLException
{
  int base = complexTest.getInt(1);
  int incbase = complexTest.getInt(2);
  Timestamp ctime = complexTest.getTimestamp(3);
  return "Base = \"" + base +
    "\", incbase = \"" + incbase +
    "\", ctime = \"" + ctime + "\"";
}

Returning complex types

Java does not stipulate any way to create a ResultSet from scratch. Hence, returning a ResultSet is not an option. The SQL-2003 draft suggest that a complex return value instead is handled as an IN/OUT parameter and PL/Java implements it that way. If you declare a function that returns a complex type, you will need to use a Java method with boolean return type with a last parameter of type java.sql.ResultSet. The parameter will be initialized to an empty updateable ResultSet that contains exactly one row.

Assume that we still have the complexTest type created above.

CREATE FUNCTION createComplexTest(int, int)
  RETURNS complexTest
  AS 'foo.fee.Fum.createComplexTest'
  IMMUTABLE LANGUAGE java;

The PL/Java method resolve will now find the following method in the Fum class:

public static boolean complexReturn(int base, int increment, ResultSet receiver)
throws SQLException
{
  receiver.updateInt(1, base);
  receiver.updateInt(2, base + increment);
  receiver.updateTimestamp(3, new Timestamp(System.currentTimeMillis()));
  return true;
}

The return value denotes if the receiver should be considered as a valid tuple (true) or NULL (false).

Functions returning sets

Returning sets is tricky. You don't want to first build a set and then return it since large sets would eat too much resources. Its far better to produce one row at a time. Incidentally, that's exactly what the PostgreSQL backend expects a function with SETOF return to do. You can return a SETOF a scalar type such as an int, float or varchar, or you can return a SETOF a complex type.

 

Returning a SETOF <scalar type>

In order to return a set of a scalar type, you need create a Java method that returns something that implements the java.util.Iterator interface. Here's an example of a method that returns a SETOF varchar:

CREATE FUNCTION javatest.getSystemProperties()
  RETURNS SETOF varchar
  AS 'foo.fee.Bar.getNames'
  IMMUTABLE LANGUAGE java;

The very rudimentary java method that returns an interator:

package foo.fee;
import java.util.Iterator;

public class Bar
{
    public static Iterator getNames()
    {
        ArrayList names = new ArrayList();
        names.add("Lisa");
        names.add("Bob");
        names.add("Bill");
        names.add("Sally");
        return names.iterator();
    }
}

Returning a SETOF <complex type>

A method returning a SETOF <complex type> must use either the interface org.postgresql.pljava.ResultSetProvider or org.postgresql.pljava.ResultSetHandle. The reason for having two interfaces is that they cater for optimal handling of two distinct use cases. The former is great when you want to dynamically create each row that is to be returned from the SETOF function. The latter makes sense when you want to return the result of an executed query.

Using the ResultSetProvider interface

This interface has two methods. The boolean assignRowValues(java.sql.ResultSet tupleBuilder, int rowNumber) and the void close() method. The PostgreSQL query evaluator will call the assignRowValues repeatedly until it returns false or until the evaluator decides that it does not need any more rows. It will then call close.

You can use this interface the following way:

CREATE FUNCTION javatest.listComplexTests(int, int)
  RETURNS SETOF complexTest
  AS 'foo.fee.Fum.listComplexTest'
  IMMUTABLE LANGUAGE java;

The function maps to a static java method that returns an instance that implements the ResultSetProvider interface.

public class Fum implements ResultSetProvider
{
  private final int m_base;
  private final int m_increment;
  public Fum(int base, int increment)
  {
    m_base = base;
    m_increment = increment;
  }
  public boolean assignRowValues(ResultSet receiver, int currentRow)
  throws SQLException
  {
    // Stop when we reach 12 rows.
    //
    if(currentRow >= 12)
      return false;
    receiver.updateInt(1, m_base);
    receiver.updateInt(2, m_base + m_increment * currentRow);
    receiver.updateTimestamp(3, new Timestamp(System.currentTimeMillis()));
    return true;
  }
  public void close()
  {
  	// Nothing needed in this example
  }
  public static ResultSetProvider listComplexTests(int base, int increment)
  throws SQLException
  {
    return new Fum(base, increment);
  }
}

The listComplextTests method is called once. It may return null if no results are available or an instance of the ResultSetProvider. Here the Fum implements this interface so it returns an instance of itself. The method assignRowValues will then be called repeatedly until it returns false. At that time, close will be called

Using the ResultSetHandle interface

This interface is similar to the ResultSetProvider interface in that it has a close() method that will be called at the end. But instead of having the evaluator call a method that builds one row at a time, this method has a method that returns a ResultSet. The query evaluator will iterate over this set and deliver it's contents, one tuple at a time, to the caller until a call to next() returns false or the evaluator decides that no more rows are needed.

Here is an example that executes a query using a statement that it obtained using the default connection. The SQL suitable for the deployment descriptor looks like this:

CREATE FUNCTION javatest.listSupers()
  RETURNS SETOF pg_user
  AS 'org.postgresql.pljava.example.Users.listSupers'
  LANGUAGE java;

CREATE FUNCTION javatest.listNonSupers()
  RETURNS SETOF pg_user
  AS 'org.postgresql.pljava.example.Users.listNonSupers'
  LANGUAGE java;
And in the Java package org.postgresql.pljava.example a class Users is added:
public class Users implements ResultSetHandle
{
  private final String m_filter;
  private Statement m_statement;

  public Users(String filter)
  {
    m_filter = filter;
  }

  public ResultSet getResultSet()
  throws SQLException
  {
    m_statement = DriverManager.getConnection("jdbc:default:connection").createStatement();
    return m_statement.executeQuery("SELECT * FROM pg_user WHERE " + m_filter);
  }

  public void close()
  throws SQLException
  {
    m_statement.close();
  }

  public static ResultSetHandle listSupers()
  {
    return new Users("usesuper = true");
  }

  public static ResultSetHandle listNonSupers()
  {
    return new Users("usesuper = false");
  }
}

Triggers

The method signature of a trigger is predefined. A trigger method must always return void and have a org.postgresql.pljava.TriggerData parameter. No more, no less. The TriggerData interface provides access to two ResultSet instances; one representing the old row and one representing the new. The old row is read-only, the new row is updateable.

The sets are only available for triggers that are fired ON EACH ROW. Delete triggers have no new row, and insert triggers have no old row. Only update triggers have both.

In addition to the sets, several boolean methods exists to gain more information about the trigger. Here's an example trigger:

CREATE TABLE mdt (
  id int4,
  idesc text,
  moddate timestamp DEFAULT CURRENT_TIMESTAMP NOT NULL);

CREATE FUNCTION moddatetime()
  RETURNS trigger
  AS 'org.postgresql.pljava.example.Triggers.moddatetime'
  LANGUAGE java";

CREATE TRIGGER mdt_moddatetime
  BEFORE UPDATE ON mdt
  FOR EACH ROW
  EXECUTE PROCEDURE moddatetime (moddate);

The Java method in class org.postgresql.pljava.example.Triggers looks like this:

/**
 * Update a modification time when the row is updated.
 */
static void moddatetime(TriggerData td)
throws SQLException
{
  if(td.isFiredForStatement())
    throw new TriggerException(td, "can't process STATEMENT events");

  if(td.isFiredAfter())
    throw new TriggerException(td, "must be fired before event");

  if(!td.isFiredByUpdate())
    throw new TriggerException(td, "can only process UPDATE events");

  ResultSet _new = td.getNew();
  String[] args = td.getArguments();
  if(args.length != 1)
    throw new TriggerException(td, "one argument was expected");

  _new.updateTimestamp(args[0], new Timestamp(System.currentTimeMillis()));
}

Using JDBC

PL/Java contains a JDBC driver that maps to the PostgreSQL SPI functions. A connection that maps to the current transaction can be obtained using the following statement:

Connection conn = DriverManager.getConnection("jdbc:default:connection"); 

From there on, you can prepare and execute statements, just like with any other JDBC connection. There are a couple of limitations though:

Exception handling

You can catch and handle an exception in the Postgres backend just like any other exceptoin. The backend ErrorData structure is exposed as a property in a class called org.postgresql.pljava.ServerException (derived from java.sql.SQLException) and the Java try/catch mechanism is synchronized with the backend mechanism.

Important Note:

You will not be able to continue executing backend functions until your function has returned and the error has been propagated when the backend has generated an exception unless you have used a savepoint. When a savepoint is rolled back, the exceptional condition is reset and you can continue your execution.

Savepoints

PostgreSQL savepoints are exposed using the java.sql.Connection interface. Two restrictions apply.

Logging

PL/Java uses the standard Java 1.4 Logger. Hence, you can write things like:

Logger.getAnonymousLogger().info( "Time is " + new Date(System.currentTimeMillis()));

At present, the logger is hardwired to a handler that maps the current state of the PostgreSQL configuration setting log_min_messages to a valid Logger level and that outputs all messages using the backend function elog(). The following mapping apply between the Logger levels and the PostgreSQL backend levels.

java.util.logging.Level PostgreSQL level
SEVERE ERROR
WARNING WARNING
INFO INFO
FINE DEBUG1
FINER DEBUG2
FINEST DEBUG3

Security

Installation

Only a PostgreSQL super user can install PL/Java. The PL/Java utility functions are installed using SECURITY DEFINER so that they execute with the access permissions that where granted to the creator of the functions.

Trusted language

PL/Java is now a TRUSTED language. PostgreSQL stipulates that a language marked as trusted has no access to the filesystem and PL/Java enforces this. Any user can create and access functions or triggers in a trusted language. PL/Java also installs a language handler for the language "javaU". This version is not trusted and only a superuser can create new functions that use it. Any user can still call the functions.

Execution of the deployment descriptor

The install_jar, replace_jar, and remove_jar, optionally executes commands found in a SQL deployment descriptor. Such commands are executed with the permissions of the caller. In other words, although the utility function is declared with SECURITY DEFINER, it switches back to the session user during execution of the deployment descriptor commands.

Classpath manipulation

The function set_classpath requires the caller of the function has been granted CREATE permission on the affected schema.

Module Configuration.

PL/Java makes use of PostgreSQL custom variable classes in the postgresql.conf configuration file to add some configuration parameters. PL/Java introduces a custom variable class named "pljava". Here's a sample postgresql.conf entry using all (3) of the variables currently introduced:

 

# define "pljava" as a custom variable class. This is a comma separated
# list of names.
#
custom_variable_classes = 'pljava'

# define the class path that the JVM will use when loading the
# initial library. Only meaningful for non GCJ installations
#
pljava.classpath = '/home/Tada/pljava/build/pljava.jar'

# Set the size of the prepared statement MRU cache
#
pljava.statement_cache_size = 10

# If true, lingering savepoints will be released on function exit. If false,
# the will be rolled back
#
pljava.release_lingering_savepoints = true

# Define startup options for the Java VM.
#
pljava.vmoptions = '-Xmx64M'

# Setting debug to true will cause the postgres process to go
# into a sleep(1) loop on its first call to java. This variable is
# only useful if you want to debug the PL/Java internal C code.
#
pljava.debug = false