Chapter 9. SQL-Invoked Routines

Fred Toussi

The HSQL Development Group

$Revision: 6692 $

Copyright 2010-2024 Fred Toussi. Permission is granted to distribute this document without any alteration under the terms of the HSQLDB license. Additional permission is granted to the HSQL Development Group to distribute this document with or without alterations under the terms of the HSQLDB license.

2024-10-25

Table of Contents

Overview
Routine Definition
Routine Characteristics
SQL Language Routines (PSM)
Advantages and Disadvantages
Routine Statements
Compound Statement
Table Variables
Variables
Cursors
Handlers
Assignment Statement
Select Statement : Single Row
Formal Parameters
Iterated Statements
Iterated FOR Statement
Conditional Statements
Return Statement
Control Statements
Raising Exceptions
Routine Polymorphism
Returning Data From Procedures
Recursive Routines
Java Language Routines (SQL/JRT)
Polymorphism
Java Language Procedures
Java Static Methods
Legacy Support
Securing Access to Classes and Routines
Warning
User-Defined Aggregate Functions
Definition of Aggregate Functions
SQL PSM Aggregate Functions
Java Aggregate Functions

Overview

SQL-invoked routines are functions and procedures called from SQL. HyperSQL 2.7 supports routines conforming to two parts of the SQL Standard. Routines written in the SQL language are supported in conformance to SQL/PSM (Persistent Stored Modules) specification. Routines written in Java are supported in broad conformance to SQL/JRT specification. In addition, HyperSQL's previous non-standard support for calling Java routines without prior method definition is retained and enhanced in the latest version by extending the SQL/JRT specification.

HyperSQL also supports user-defined aggregate functions written in the SQL language or Java. This feature is an extension to the SQL Standard.

SQL-invoked routines are schema-level objects. Naming and referencing follows conventions common to all schema objects. The same routine name can be defined in two different schemas and used with schema-qualified references.

A routine is either a procedure or a function.

A function:

  • is defined with CREATE FUNCTION

  • always returns a single value or a single table

  • does not modify the data in the database

  • is used as part of an SQL statement such as a SELECT statement, as well as called separately using the CALL statement

  • can have parameters

  • can be polymorphic

A procedure:

  • is defined with CREATE PROCEDURE

  • can return zero to multiple values or result sets

  • can modify the data in the database

  • is called separately, using the CALL statement

  • can have parameters

  • can be polymorphic

Definition of routine signature and characteristics, name resolution and invocation are all implemented uniformly for routines written in SQL or Java.

Access to routines can be granted to users with GRANT EXECUTE or GRANT ALL. For example, GRANT EXECUTE ON myroutine TO PUBLIC.

Routine Definition

SQL-Invoked Routines, whether PSM or JRT, are defined using a SQL statement with the same syntax. The part that is different is the <routine body> which consists of SQL statements in PSM routines or a reference to a Java method in JRT routines.

Details of Routine definition are discussed in this section. You may start by reading the next two sections which provide several examples before reading this section for the details.

Routine definition has several mandatory or optional clauses. The complete BNF supported by HyperSQL and the remaining clauses are documented in this section.

CREATE FUNCTION

CREATE PROCEDURE

routine definition

Routine definition is similar for procedures and functions. A function definition has the mandatory <returns clause> which is discussed later. The description given so far covers the essential elements of the specification with the BNF given below.

<schema procedure> ::= CREATE PROCEDURE <schema qualified routine name> <SQL parameter declaration list> <routine characteristics> <routine body>

<schema function> ::= CREATE FUNCTION <schema qualified routine name> <SQL parameter declaration list> <returns clause> <routine characteristics> <routine body>

Parameter declaration list has been described above. For SQL/JRT routines, the <SQL parameter name> is optional while for SQL/PSM routines, it is required. If the <parameter mode> of a parameter is OUT or INOUT, it must be specified. The BNF is given below:

<SQL parameter declaration list> ::= <left paren> [ <SQL parameter declaration> [ { <comma> <SQL parameter declaration> }... ] ] <right paren>

<SQL parameter declaration> ::= [ <parameter mode> ] [ <SQL parameter name> ] <parameter type>

<parameter mode> ::= IN | OUT | INOUT

<parameter type> ::= <data type>

Return Value and Table Functions

RETURNS

returns clause

The <returns clause> specifies the type of the return value of a function (not a procedure). For all SQL/PSM and SQL/JRT functions, this is usually a type definition which can be a built-in type, a DOMAIN type or a DISTINCT type. For example, RETURNS INTEGER.

The return type can alternatively be a TABLE definition. Functions that return a table are called table functions. Table functions are used differently from normal functions. A table function can be used in an SQL query expression exactly where a normal table or view is allowed.

If a <returns table type> is defined for an SQL/PSM function, the following expression is used inside the function to return a table: RETURN TABLE ( <query expression> ); In the example blow, a table with two columns is returned.

 RETURN TABLE ( SELECT a, b FROM atable WHERE e = 10 );

Functions that return a table are designed to be used in SELECT statements using the TABLE keyword to form a joined table.

When a JDBC CallableStatement is used to CALL the function, the table returned from the function call is returned and can be accessed with the getResultSet() method of the CallableStatement.

<returns clause> ::= RETURNS <returns type>

<returns type> ::= <returns data type> | <returns table type>

<returns table type> ::= TABLE <table function column list>

<table function column list> ::= <left paren> <table function column list element> [ { <comma> <table function column list element> } ... ] <right paren>

<table function column list element> ::= <column name> <data type>

<returns data type> ::= <data type>

routine body

routine body

Routine body is either one or more SQL statements or a Java reference. The user that defines the routine by issuing the CREATE FUNCTION or CREATE SCHEMA command must have the relevant access rights to all tables, sequences, routines, etc. that are accessed by the routine. If another user is given EXECUTE privilege on the routine, then there are two possibilities, depending on the <rights clause>. This clause refers to the access rights that are checked when a routine is invoked. The default is SQL SECURITY DEFINER, which means access rights of the definer are used; therefore, no extra checks are performed when the other user invokes the routine. The alternative SQL SECURITY INVOKER means access rights on all the database objects referenced by the routine are checked for the invoker. This alternative is not supported by HyperSQL.

<routine body> ::= <SQL routine spec> | <external body reference>

<SQL routine spec> ::= [ <rights clause> ] <SQL routine body>

<rights clause> ::= SQL SECURITY INVOKER | SQL SECURITY DEFINER

SQL routine body

SQL routine body

The routine body of an SQL routine consists of an statement.

<SQL routine body> ::= <SQL procedure statement>

EXTERNAL NAME

external body reference

External name specifies the qualified name of the Java method associated with this routine. HyperSQL only supports Java methods within the classpath. The <external Java reference string> is a quoted string which starts with CLASSPATH: and is followed by the Java package, class and method names separated with dots. HyperSQL does not currently support the optional <Java parameter declaration list>.

<external body reference> ::= EXTERNAL NAME <external Java reference string>

<external Java reference string> ::= <jar and class name> <period> <Java method name> [ <Java parameter declaration list> ]

Routine Characteristics

The <routine characteristics> clause covers several sub-clauses

<routine characteristics> ::= [ <routine characteristic>... ]

<routine characteristic> ::= <language clause> | <parameter style clause> | SPECIFIC <specific name> | <deterministic characteristic> | <SQL-data access indication> | <null-call clause> | <returned result sets characteristic> | <savepoint level indication>

LANGUAGE

language clause

The <language clause> refers to the language in which the routine body is written. It is either SQL or Java. The default is SQL, so JAVA must be specified for SQL/JRT routines.

<language clause> ::= LANGUAGE <language name>

<language name> ::= SQL | JAVA

The parameter style is not allowed for SQL routines. It is optional for Java routines and, in HyperSQL, the only value allowed is JAVA.

<parameter style> ::= JAVA

SPECIFIC NAME

specific name

The SPECIFIC <specific name> clause is optional but the engine will creates an automatic name if it is not present. When there are several versions of the same routine, the <specific name> is used in schema manipulation statements to drop or alter a specific version. The <specific name> is a user-defined name. It applies to both functions and procedures. In the examples below, two versions of a functions are defined with the same name and different parameter types. A specific name is specified for each function.

 CREATE FUNCTION an_hour_before(t TIMESTAMP)
   RETURNS TIMESTAMP
   NO SQL
   LANGUAGE JAVA PARAMETER STYLE JAVA
   SPECIFIC an_hour_before_or_now_with_timestamp
   EXTERNAL NAME 'CLASSPATH:org.npo.lib.nowLessAnHour'

 CREATE FUNCTION an_hour_before (e_type INT)
   RETURNS TIMESTAMP SPECIFIC an_hour_before_max_with_int
   RETURN (SELECT MAX(event_time) FROM atable WHERE event_type = e_type) - 1 HOUR

DETERMINISTIC

deterministic characteristic

The <deterministic characteristic> clause indicates that a routine is deterministic or not. Deterministic means the routine does not reference random values, external variables, or time of invocation. The default is NOT DETERMINISTIC. It is essential to declare this characteristic correctly for an SQL/JRT routine, as the engine does not know the contents of the Java code, which could include calls to methods returning random or time sensitive values.

<deterministic characteristic> ::= DETERMINISTIC | NOT DETERMINISTIC

SQL DATA access

SQL DATA access characteristic

The <SQL-data access indication>  clause indicates the extent to which a routine interacts with the database or the data stored in the database tables in different schemas (SQL DATA).

NO SQL means no SQL command is issued in the routine body and can be used only for SQL/JRT functions.

CONTAINS SQL means some SQL commands are used, but they do not read or modify the SQL data. READS SQL DATA and MODIFIES SQL DATA are self-explanatory.

A CREATE PROCEDURE definition can use MODIFIES SQL DATA. This is not allowed in CREATE FUNCTION. Note that a PROCEDURE or a FUNCTION may have internal tables or return a table which is populated by the routine's statements. These tables are not considered SQL DATA, therefore there is no need to specify MODIFIES SQL DATA for such routines.

<SQL-data access indication> ::= NO SQL | CONTAINS SQL | READS SQL DATA | MODIFIES SQL DATA

NULL INPUT

null call clause

Null Arguments

The <null-call clause> is used only for functions. If a function returns NULL when any of the calling arguments is null, then by specifying RETURNS NULL ON NULL INPUT, calls to the function are known to be redundant and do not take place when an argument is null. This simplifies the coding of the SQL/JRT Java methods and improves performance at the same time.

<null-call clause> ::= RETURNS NULL ON NULL INPUT | CALLED ON NULL INPUT

SAVEPOINT LEVEL

transaction impact

The <savepoint level indication> is used only for procedures and refers to the visibility of existing savepoints within the body of the procedure. If NEW SAVEPOINT LEVEL is specified, savepoints that have been declared prior to calling the procedure become invisible within the body of the procedure. HyperSQL’s implementation accepts only NEW SAVEPOINT LEVEL.

<savepoint level indication> ::= NEW SAVEPOINT LEVEL | OLD SAVEPOINT LEVEL

DYNAMIC RESULT SETS

returned result sets characteristic

The <returned result sets characteristic> is used with SQL/PSM and SQL/JRT procedures (not with functions). The maximum number of result sets that a procedure may return can be specified with the clause below. The default is zero. If you want your procedure to return result sets, you must specify the maximum number of result sets that your procedure may return. Details are discussed in the next sections.

<returned result sets characteristic> ::= DYNAMIC RESULT SETS <maximum returned result sets>

SQL Language Routines (PSM)

The PSM (Persistent Stored Module) specification extends the SQL language with structures and control statements such as conditional and loop statements. Both SQL Function and SQL procedure bodies use the same syntax, with minor exceptions.

The routine body is a SQL statement. In its simplest form, the body is a single SQL statement. A simple example of a function is given below:

 CREATE FUNCTION an_hour_before (t TIMESTAMP)
   RETURNS TIMESTAMP
   RETURN t - 1 HOUR

An example of the use of the function in an SQL statement is given below:

 SELECT an_hour_before(event_timestamp) AS notification_timestamp, event_name FROM events;

The CUSTOMERS and ADDRESSES tables as defined below are used in our examples:

 CREATE TABLE customers(id INTEGER GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, firstname VARCHAR(50), lastname VARCHAR(50), added TIMESTAMP);

 CREATE TABLE addresses(id INTEGER GENERATED BY DEFAULT AS IDENTITY, customerid INTEGER, address VARCHAR(50));

 ALTER TABLE addresses ADD CONSTRAINT fk_addr FOREIGN KEY(customerid) REFERENCES customers(id)

A simple example of a procedure to insert into the CUSTOMERS table is given below. Note the keyword DEFAULT is used to insert the generated IDENTITY value into the ID column. Also note the BEGIN ATOMIC and END are optional when there is only one statement in the procedure.

 CREATE PROCEDURE new_customer(firstname VARCHAR(50), lastname VARCHAR(50))
   MODIFIES SQL DATA
   INSERT INTO CUSTOMERS VALUES DEFAULT, firstname, lastname, CURRENT_TIMESTAMP;

An example of the use of the procedure is given below:

 CALL new_customer('JOHN', 'SMITH');

The routine body is often a compound statement. A compound statement can contain one or more SQL statements, which can include control statements, as well as nested compound statements.

Please note carefully the use of <semicolon>, which is required at the end of some statements but not accepted at the end of others.

Advantages and Disadvantages

SQL Language Routines (PSM) have certain advantages over Java Language Routines (SQL/JRT) and a couple of disadvantages.

  • SQL language routines (PSM) do not rely on custom Java classes to be present on the classpath. The databases that use them are therefore more portable.

  • For a routine that accesses SQL DATA, all the SQL statements in an SQL routine are known and monitored by the engine. The engine will not allow a table, routine or sequence that is referenced in an SQL routine to be dropped, or its structure modified in a way that will break the routine execution. The engine does not keep this information about a Java routine.

  • Because the statements in an SQL routine are known to the engine, the execution of an SQL routine locks all the database objects it needs to access before the actual execution. With Java routines, locks are obtained during execution and this may cause additional delays in multi-threaded access to the database.

  • For routines that do not access SQL DATA, Java routines (SQL/JRT) may be faster if they perform extensive calculations.

  • Only Java routines can access external programs and resources directly.

Routine Statements

The following SQL Statements can be used only in routines. These statements are covered in this section.

<handler declaration>

<table variable declaration>

<variable declaration>

<declare cursor>

<assignment statement>

<compound statement>

<case statement>

<if statement>

<while statement>

<repeat statement>

<for statement>

<loop statement>

<iterate statement

<leave statement>

<signal statement>

<resignal statement>

<return statement>

<select statement: single row>

<open statement>

The following SQL Statements can be used in procedures but not in generally in functions (they can be used in functions only to change the data in a local table variable) . These statements are covered in other chapters of this Guide.

<call statement>

<delete statement>

<insert statement>

<update statement>

<merge statement>

Transaction statements such as COMMIT and ROLLBACK are not allowed in the body of a function or procedure. When the session is in auto-commit mode, the commit takes place after the execution of the whole procedure has been completed. No commit is performed during the execution.

As shown in the examples below, the formal parameters and the variables of the routine can be used in statements, similar to the way a column reference is used.

Compound Statement

A compound statement is enclosed in a BEGIN / END block with optional labels. It can contain one or more <table variable declaration>, <SQL variable declaration>, <declare cursor> or <handler declaration> before at least one SQL statement. The BNF is given below:

<compound statement> ::= [ <beginning label> <colon> ] BEGIN [[NOT] ATOMIC]

[{<table variable declaration> <semicolon>} ...]

[{<SQL variable declaration> <semicolon>} ...]

[{<declare cursor> <semicolon>} ...]

[{<handler declaration> <semicolon>}...]

{<SQL procedure statement> <semicolon>} ...

END [ <ending label> ]

An example of a simple compound statement body is given below. It performs the common task of inserting related data into two table. The IDENTITY value that is automatically inserted in the first table is retrieved using the IDENTITY() function and inserted into the second table. Other examples show more complex compound statements. Note polymorphism allows the previously defined NEW_CUSTOMER procedure to coexist with this one as their parameter lists are different.

 CREATE PROCEDURE new_customer(firstname VARCHAR(50), lastname  VARCHAR(50), address VARCHAR(100))
   MODIFIES SQL DATA
     BEGIN ATOMIC
     INSERT INTO customers VALUES (DEFAULT, firstname, lastname, CURRENT_TIMESTAMP);
     INSERT INTO addresses VALUES (DEFAULT, IDENTITY(), address);
   END

Table Variables

A <table variable declaration> defines the name and columns of a local table, that can be used in the routine body. The table cannot have constraints. Table variable declarations are made before scalar variable declarations.

 BEGIN ATOMIC
   DECLARE TABLE temp_table (col_a INT, col_b VARCHAR(50);
   DECLARE temp_id INTEGER;
   -- more statements
 END

Variables

A <variable declaration> defines the name and data type of the variable and, optionally, its default value. In the next example, a variable is used to hold the IDENTITY value. In addition, the formal parameters of the procedure are identified as input parameters with the use of the optional IN keyword. This procedure does exactly the same job as the procedure in the previous example.

 CREATE PROCEDURE new_customer(IN firstname VARCHAR(50), IN lastname VARCHAR(50), IN address VARCHAR(100))
     MODIFIES SQL DATA
   BEGIN ATOMIC
     DECLARE temp_id INTEGER;
     INSERT INTO CUSTOMERS VALUES (DEFAULT, firstname, lastname, CURRENT_TIMESTAMP);
     SET temp_id = IDENTITY();
     INSERT INTO ADDRESSES VALUES (DEFAULT, temp_id, address);
   END

The BNF for variable declaration is given below:

DECLARE variable

SQL variable declaration

<SQL variable declaration> ::= DECLARE <variable name list> <data type> [DEFAULT <default value>]

<variable name list> ::= <variable name> [ { <comma> <variable name> }... ]

Examples of variable declaration are given below. Note that in a DECLARE statement with multiple comma-separated variable names, the type and the default value applies to all the variables in the list:

 BEGIN ATOMIC
   DECLARE temp_zero DATE;
   DECLARE temp_one, temp_two INTEGER DEFAULT 2;
   DECLARE temp_three VARCHAR(20) DEFAULT 'no name';
   -- more statements ...
   SET temp_zero = DATE '2010-03-18';
   SET temp_two = 5;
   -- more statements ...
 END

Cursors

A <declare cursor> statement is used to declare a SELECT statement. The current usage of this statement in HyperSQL is exclusively to return a result set from a procedure. The result set is returned to the JDBC CallableStatement object that calls the procedure. The getResultSet() method of CallableStatement is then used to retrieve the JDBC ResultSet.

In the <routine definition>, the DYNAMIC RESULT SETS clause must be used to specify a value above zero. The DECLARE CURSOR statement is used after any variable declaration in compound statement block. The SELECT statement should be followed with FOR READ ONLY to avoid possible error messages. The <open statement> is then executed for the cursor at the point where the result set should be populated.

After the procedure is executed with a JDBC CallableStatement execute() or executeQery() call, all the result sets that were opened are returned to the JDBC CallableStatement.

Calling getResultSet() will return the first ResultSet. When there are multiple result sets, the getMoreResults() method of the Callable statement is called to move to the next ResultSet, before getResultSet() is called to return the next ResultSet. See the Data Access and Change chapter on the syntax for declaring the cursor.

The simple example below returns a result set containing the list of recently added customers since the data used as argument:

  CREATE PROCEDURE recent_customers(IN since_date DATE)
     READS SQL DATA DYNAMIC RESULT SETS 1
   BEGIN ATOMIC
   DECLARE temp_zero DATE;
   DECLARE result CURSOR WITH RETURN FOR SELECT * FROM CUSTOMERS WHERE added > since_date;
   -- you can have more more statements here ...
   OPEN result;
 END

Handlers

A <handler declaration> defines the course of action when an exception or warning is raised during the execution of the compound statement. A compound statement may have one or more handler declarations. These handlers become active when code execution enters the compound statement block and remain active in any sub-block and statement within the block. The handlers become inactive when code execution leaves the block.

In the previous example of the new_customer procedure, if an exception is thrown during the execution of either SQL statement, the execution of the compound statement is terminated and the exception is propagated and thrown by the CALL statement for the procedure. All changes made by the procedure are rolled back.

A handler declaration can resolve the thrown exception within the compound statement without propagating it, and allow the execution of the compound statement to continue.

We add a check constraint to the CUSTOMERS table to disallow empty names.

 ALTER TABLE customers ADD CONSTRAINT check_names CHECK (CHAR_LENGTH(FIRSTNAME) > 1 AND CHAR_LENGTH(LASTNAME) > 2) ;

An attempt to insert invalid names will now result in the check constraint throwing an exception. In the example below, the UNDO handler declaration catches any exception that is thrown during the execution of the compound statement inside the BEGIN ... END block. As it is an UNDO handler, all the changes to data performed within the compound statement ( BEGIN ... END block) are rolled back. The procedure then returns without throwing an exception. We can define a label for each BEGIN / END block, as done in this example.

 CREATE PROCEDURE new_customer(IN firstname VARCHAR(50), IN lastname VARCHAR(50), IN address VARCHAR(100))
     MODIFIES SQL DATA
   label_one: BEGIN ATOMIC
     DECLARE temp_id INTEGER;
     DECLARE UNDO HANDLER FOR SQLEXCEPTION;
     INSERT INTO CUSTOMERS VALUES (DEFAULT, firstname, lastname, CURRENT_TIMESTAMP);
     SET temp_id = IDENTITY();
     INSERT INTO ADDRESSES VALUES (DEFAULT, temp_id, address);
   END

Other types of hander are CONTINUE and EXIT handlers. A CONTINUE handler ignores any exception and proceeds to the next statement in the block. An EXIT handler terminates execution without undoing the data changes performed by the previous (successful) statements.

The conditions can be general conditions, or specific conditions.

Among general conditions that can be specified, SQLEXCEPTION covers all exceptions, SQLWARNING covers all warnings, while NOT FOUND covers the not-found condition, which is raised when a DELETE, UPDATE, INSERT or MERGE statement completes without actually affecting any row.

Alternatively, one or more specific conditions can be specified (separated with commas) which apply to specific exceptions or warnings or classes or exceptions or warnings. A specific condition is specified with SQLSTATE <value>, for example SQLSTATE 'W_01003' specifies the warning raised after a SQL statement is executed which contains an aggregate function which encounters a null value during execution. An example is given below which activates the handler when either of the two warnings is raised:

 DECLARE UNDO HANDLER FOR SQLSTATE 'W_01003', 'W_01004';

The BNF for <handler declaration> is given below:

DECLARE HANDLER

declare handler statement

<handler declaration> ::= DECLARE {UNDO | CONTINUE | EXIT} HANDLER FOR {SQLEXCEPTION | SQLWARNING | NOT FOUND} | { SQLSTATE <state value> [, ...]} [<SQL procedure statement>];

A handler declaration may specify an <SQL procedure statement> to be performed when the handler is activated. In the example below the handler performs the UNDO as in the previous example then inserts the (invalid) data into a separate table. We create a new table for the invalid attempts.

 CREATE TABLE invalid_customers (LIKE customers) ;
 CREATE PROCEDURE new_customer(IN firstname VARCHAR(50), IN lastname VARCHAR(50), IN address VARCHAR(100))
     MODIFIES SQL DATA
   label_one: BEGIN ATOMIC
     DECLARE temp_id INTEGER;
     DECLARE UNDO HANDLER FOR SQLEXCEPTION
     INSERT INTO invalid_customers VALUES(DEFAULT, firstname, lastname, address);
     -- last statement is part of the handler; it is called only if the next statements throw an exception

     INSERT INTO CUSTOMERS VALUES (DEFAULT, firstname, lastname, CURRENT_TIMESTAMP);
     SET temp_id = IDENTITY();
     INSERT INTO ADDRESSES VALUES (DEFAULT, temp_id, address);
   END

The <SQL procedure statement> in the handler declaration is required by the SQL Standard but is optional in HyperSQL. If the execution of the <SQL procedure statement> specified in the handler declaration throws an exception itself, then it is handled by the handlers that are currently active at an enclosing (outer) BEGIN ... END block. The <SQL procedure statement> can itself be a compound statement with its own handlers.

When a handler handles an exception condition such as the general SQLEXCEPTION or some specific SQLSTATE, any changes made by the statement that caused the exception will be rolled back. For example, execution of a single update statement that modifies several rows will not change any row if an exception occurs during the update of one of the rows. The handler action affects the changes made by statements that were executed successfully before the exception occurred.

Actions performed by different types of handler are listed below:

  • An UNDO handler rolls back all the data changes within the BEGIN ... END block which contains the handler declaration. The execution of the BEGIN ... END block is considered complete. If an <SQL procedure statement> is specified, it is executed after the roll back.

  • A CONTINUE handler does not roll back the data changes. It continues execution as if the last statement was successful. If an <SQL procedure statement> is specified, it is executed before continuing execution.

  • An EXIT handler does not roll back the data changes. It aborts the execution of the BEGIN ... END block which contains the handler declaration. The execution of the BEGIN ... END block is considered complete, but unlike the UNDO handler the actions are not rolled back. If an <SQL procedure statement> is specified, it is executed before aborting.

Assignment Statement

The SET statement is used for assignment. It can be used flexibly with rows or single values. The BNF is given below:

<assignment statement> ::= <singleton variable assignment> | <multiple variable assignment>

<singleton variable assignment> ::= SET <assignment target> <equals operator> <assignment source>

<multiple variable assignment> ::= SET (<variable or parameter>, ...) = <row value expression>

In the example below, the result of the SELECT is assigned to two OUT arguments. The SELECT must return one row. If it returns more than one, an exception is raised. If it returns no row, no change is made to ARG_FIRST and ARG_LAST.

  CREATE PROCEDURE get_customer_name(IN arg_id INT, OUT arg_first VARCHAR(50), OUT arg_last VARCHAR(50))
     READS SQL DATA
   BEGIN ATOMIC
   SET (arg_first, arg_last) = (SELECT firstname, lastname FROM customers WHERE id = arg_id);
 END

In the example below, the result of a function call is assigned to VAR1.

 SET var1 = SQRT(var2);

Select Statement : Single Row

A special form of SELECT can also be used for assigning values from a query to one or more arguments or variables. This works similar to a SET statement that has a SELECT statement as the source.

SELECT : SINGLE ROW

select statement: single row

<select statement: single row> ::= SELECT [ <set quantifier> ] <select list> INTO <select target list> <table expression>

<select target list> ::= <target specification> [ { <comma> <target specification> }... ]

Retrieve values from a specified row of a table and assign the fields to the specified targets. The example below has an identical effect to the SET statement in the GET_CUSTOMER_NAME procedure.

SELECT firstname, lastname INTO arg_first, arg_last FROM customers WHERE id = arg_id;

Formal Parameters

Each parameter of a procedure can be defined as IN, OUT or INOUT. An IN parameter is an input to the procedure and is passed by value. The value cannot be modified inside the procedure body. An OUT parameter is a reference for output. An INOUT parameter is a reference for both input and output. An OUT or INOUT parameter argument is passed by reference, therefore only a dynamic parameter argument or a variable within an enclosing procedure can be passed for it. The assignment statement is used to assign a value to an OUT or INOUT parameter.

In the example below, the procedure is declared with an OUT parameter. It assigns the auto-generated IDENTITY value from the INSERT statement to the OUT argument.

 CREATE PROCEDURE new_customer(OUT newid INT, IN firstname VARCHAR(50), IN lastname VARCHAR(50), IN address VARCHAR(100))
   MODIFIES SQL DATA
   BEGIN ATOMIC
     DECLARE temp_id INTEGER;
     INSERT INTO CUSTOMERS VALUES (DEFAULT, firstname, lastname, CURRENT_TIMESTAMP);
     SET temp_id = IDENTITY();
     INSERT INTO ADDRESSES VALUES (DEFAULT, temp_id, address);
     SET newid = temp_id;
   END

In the SQL session, or in the body of another stored procedure, a variable must be assigned to the OUT parameter. After the procedure call, this variable will hold the new identity value that was generated inside the procedure. If the procedure is called directly, using the JDBC CallableStatement interface, then the value of the first, OUT argument can be retrieved with a call to getInt(1)after calling the execute() method.

In the example below, a session variable, the_new_id is declared. After the call to new_customer, the value for the identity is stored in the_new_id variable. This is returned via the next VALUES statement. Alternatively, the_new_id can be used as an argument to another CALL statement. Session variables are useful during development and for SQL scripting tools.

 DECLARE the_new_id INT DEFAULT NULL;
 CALL new_customer(the_new_id, 'John', 'Smith', '10 Parliament Square'); 
 VALUES the_new_id;

Iterated Statements

Various iterated statements can be used in routines. In these statements, the <SQL statement list> consists of one or more SQL statements. The <search condition> can be any valid SQL expression of BOOLEAN type.

LOOP

loop statement

<loop statement> ::= [ <beginning label> <colon> ] LOOP <SQL statement list> END LOOP [ <ending label> ]

The LOOP statement is a simple loop without its own condition. A conditional LEAVE statement inside the loop is used to break out of the loop.

WHILE

while statement

<while statement> ::= [ <beginning label> <colon> ] WHILE <search condition> DO <SQL statement list> END WHILE [ <ending label> ]

The WHILE statement is a loop with a condition at the top, similar to Java while loop.

In the example below, multiple rows are inserted into a table in a WHILE loop:

 DECLARE my_ver INTEGER DEFAULT 2;
 loop_label: WHILE my_var < 20 DO
   INSERT INTO CUSTOMERS VALUES (DEFAULT, my_var);
   SET my_var = my_var + 1;

   -- LEAVE can be used to break the loop
   IF my_var = 15 THEN LEAVE loop_label; END IF;
 END WHILE loop_label;

REPEAT

repeat statement

<repeat statement> ::= [ <beginning label> <colon> ]

REPEAT <SQL statement list> UNTIL <search condition> END REPEAT [ <ending label>

The REPEAT statement is a loop with a condition at the bottom, similar to Java do ... while loop.

Iterated FOR Statement

The <for statement> is similar to other iterated statement, but it is always used with a cursor declaration to iterate over the rows of the result set of the cursor and perform operations using the values of each row.

FOR

for statement

<for statement> ::= [ <beginning label> <colon> ] FOR <query expression> DO <SQL statement list> END FOR [ <ending label> ]

The <query expression> is a SELECT statement. When the FOR statement is executed, the query expression is executed first and the result set is formed. Then for each row of the result set, the <SQL statement list> is executed. What is special about the FOR statement is that all the columns of the current row can be accessed by name in the statements in the <SQL statement list>. The columns are read only and cannot be updated. For example, if the column names for the select statement are ID, FIRSTNAME, LASTNAME, then these can be accessed as a variable name. The column names must be unique and not equivalent to any parameter or variable name in scope.

The FOR statement is useful for computing values over multiple rows of the result set, or for calling a procedure for some row of the result set.

In the example below, the procedure uses a FOR statement to iterate over the rows for a customer with lastname equal to lastname_p. No action is performed for the first row, but for all the subsequent rows, the row is deleted from the table.

Notes: The result set for the SELECT statement is built only once, before processing the statements inside the FOR block begins. For all the rows of the SELECT statement apart from the first row, the row is deleted from the customer table. The WHERE condition uses the automatic variable id, which holds the customer.id value for the current row of the result set, to delete the row. The procedure updates the val_p argument and when it returns, the val_p represents the total count of rows with the given lastname before the duplicates were deleted.

 CREATE PROCEDURE delete_extra_customers(INOUT val_p INT, IN lastname_p VARCHAR(20)) 
 MODIFIES SQL DATA
 BEGIN ATOMIC
   SET val_p = 0;
   for_label: FOR SELECT * FROM customers WHERE lastname = lastname_p DO
     IF  val_p > 0 THEN
       DELETE FROM customers WHERE customers.id = id;
     END IF;
     SET val_p = val_p + 1;
   END FOR for_label;
 END

Conditional Statements

There are two types of CASE ... WHEN statement and the IF ... THEN statement.

CASE WHEN

case when statement

The simple case statement uses a <case operand> as the predicand of one or more predicates. For the right part of each predicate, it specifies one or more SQL statements to execute if the predicate evaluates TRUE. If the ELSE clause is not specified, at least one of the search conditions must be true, otherwise an exception is raised.

<simple case statement> ::= CASE <case operand> <simple case statement when clause>... [ <case statement else clause> ] END CASE

<simple case statement when clause> ::= WHEN <when operand list> THEN <SQL statement list>

<case statement else clause> ::= ELSE <SQL statement list>

A skeletal example is given below. The variable var_one is first tested for equality with 22 or 23 and if the test evaluates to TRUE, then the INSERT statement is performed and the statement ends. If the test does not evaluate to TRUE, the next condition test, which is an IN predicate, is performed with var_one and so on. The statement after the ELSE clause is performed if none the previous tests returns TRUE.

CASE var_one
  WHEN 22, 23 THEN INSERT INTO t_one ...;
  WHEN IN (2, 4, 5) THEN DELETE FROM t_one WHERE ...;
  ELSE UPDATE t_one ...;
  END CASE

The searched case statement uses one or more search conditions, and for each search condition, it specifies one or more SQL statements to execute if the search condition evaluates TRUE. An exception is raised if there is no ELSE clause and none of the search conditions evaluates TRUE.

<searched case statement> ::= CASE <searched case statement when clause>... [ <case statement else clause> ] END CASE

<searched case statement when clause> ::= WHEN <search condition> THEN <SQL statement list>

The example below is partly a rewrite of the previous example, but a new condition is added:

 CASE WHEN var_one = 22 OR var_one = 23 THEN INSERT INTO t_one ...;
   WHEN var_one IN (2, 4, 5) THEN DELETE FROM t_one WHERE ...;
   WHEN var_two IS NULL THEN UPDATE t_one ...;
   ELSE UPDATE t_one ...;
   END CASE

IF

if statement

The if statement is very similar to the searched case statement. The difference is that no exception is raised if there is no ELSE clause and no search condition evaluates TRUE.

<if statement> ::= IF <search condition> <if statement then clause> [ <if statement elseif clause>... ] [ <if statement else clause> ] END IF

<if statement then clause> ::= THEN <SQL statement list>

<if statement elseif clause> ::= ELSEIF <search condition> THEN <SQL statement list>

<if statement else clause> ::= ELSE <SQL statement list>

Return Statement

The RETURN statement is required and used only in functions. The body of a function is either a RETURN statement, or a compound statement that contains a RETURN statement.

The return value of a FUNCTION can be assigned to a variable, or used inside an SQL statement.

An SQL/PSM function or an SQL/JRT function can return a single result when the function is defined as RETURNS TABLE ( .. )

To return a table from a SELECT statement, you should use a return statement such as RETURN TABLE( SELECT ...) in an SQL/PSM function. For an SQL/JRT function, the Java method should return a JDBC ResultSet instance.

To call a function from JDBC, use a java.sql.CallableStatement instance. The getResultSet() call can be used to access the ResultSet returned from a function that returns a result set. If the function returns a scalar value, the returned result has a single column and a single row which contains the scalar returned value.

RETURN

return statement

<return statement> ::= RETURN <return value>

<return value> ::= <value expression> | NULL

Return a value from an SQL function. If the function is defined as RETURNS TABLE, then the value is a TABLE expression such as RETURN TABLE(SELECT ...) otherwise, the value expression can be any scalar expression. In the examples below, the same function is written with or without a BEGIN END block. In both versions, the RETURN value is a scalar expression.

 CREATE FUNCTION an_hour_before_max (e_type INT)
   RETURNS TIMESTAMP
   RETURN (SELECT MAX(event_time) FROM atable WHERE event_type = e_type) - 1 HOUR

 CREATE FUNCTION an_hour_before_max (e_type INT)
   RETURNS TIMESTAMP
   BEGIN ATOMIC
     DECLARE max_event TIMESTAMP;
     SET max_event = SELECT MAX(event_time) FROM atable WHERE event_type = e_type;
     RETURN max_event - 1 HOUR;
   END

In the example below, a table is defined as the return value. The select statement provides the data to be returned.

 CREATE FUNCTION recent_customers(IN since_date DATE) 
    RETURNS TABLE(id INT, first VARCHAR(50), last VARCHAR(50))
     READS SQL DATA
   BEGIN ATOMIC
   RETURN TABLE (SELECT id, firstname, lastname FROM CUSTOMERS WHERE added > since_date);
 END

A function that returns a table can be used directly in SELECT statements. For example:

SELECT * FROM TABLE(recent_customers(CURRENT_DATE - 2 DAY))

Control Statements

In addition to the RETURN statement, the following statements can be used in specific contexts.

ITERATE STATEMENT

The ITERATE statement can be used to cause the next iteration of a labelled iterated statement (a WHILE, REPEAT or LOOP statement). It is similar to the "continue" statement in C and Java.

<iterate statement> ::= ITERATE <statement label>

LEAVE STATEMENT

The LEAVE statement can be used to leave a labelled block. When used in an iterated statement, it is similar to the "break" statement is C and Java. But it can be used in compound statements as well.

<leave statement> ::= LEAVE <statement label>

Raising Exceptions

Signal and Resignal Statements allow the routine to throw an exception. If used with the IF or CASE conditions, the exception is thrown conditionally.

SIGNAL

signal statement

The SIGNAL statement is used to throw an exception (or force an exception). When invoked, any exception handler for the given exception is in turn invoked. If there is no handler, the exception is propagated to the enclosing context.

In its simplest form, when there is no exception handler for the given exception, routine execution is halted, any change of data is rolled back and the routine throws the exception. By default, the message for the exception is taken from the predefined exception message for the specified SQLSTATE. A custom message can be specified with the optional SET clause.

<signal statement> ::= SIGNAL SQLSTATE <state value> [ SET MESSAGE_TEXT = <character string literal> ]

RESIGNAL

resignal statement

The RESIGNAL statement is used to throw an exception from an exception handler's <SQL procedure statement>, in effect propagating the exception to the enclosing context without further action by the currently active handlers. By default, the message for the exception is taken from the predefined exception message for the specified SQLSTATE. A custom message can be specified with the optional SET clause.

<resignal statement> ::= RESIGNAL SQLSTATE <state value> [ SET MESSAGE_TEXT = <character string literal> ]

Routine Polymorphism

More than one version of a routine can be created.

For procedures, the different versions must have different parameter counts. When the procedure is called, the parameter count determines which version is called.

For functions, the different versions can have the same or different parameter counts. When the parameter count of two versions of a function is the same, the type of parameters must be different. When the function is called, the best matching version of the function is used, according to both the parameter count and parameter types. The return type of different versions of a function can be the same or different.

Two versions of an overloaded function are given below. One version accepts TIMESTAMP while the other accepts TIME arguments.

 CREATE FUNCTION an_hour_before_or_now(t TIMESTAMP)
   RETURNS TIMESTAMP
   IF t > CURRENT_TIMESTAMP THEN
     RETURN CURRENT_TIMESTAMP;
   ELSE
     RETURN t - 1 HOUR;
   END IF

 CREATE FUNCTION an_hour_before_or_now(t TIME)
   RETURNS TIME
   CASE t
     WHEN > CURRENT_TIME THEN
       RETURN CURRENT_TIME;
     WHEN >= TIME'01:00:00' THEN
       RETURN t - 1 HOUR;
     ELSE
       RETURN CURRENT_TIME;
   END CASE

It is perfectly possible to have different versions of the routine as SQL/JRT or SQL/PSM routines.

Returning Data From Procedures

The OUT or INOUT parameters of a PROCEDURE are used to assign simple values to dynamic parameters or to variables in the calling context.

According to the Standard, an SQL/PSM or SQL/JRT procedure may also return result sets to the calling context. These result sets are dynamic in the sense that a procedure may return a different number of result sets or none at all in different invocations. The SQL Standard uses a mechanism called CURSORS for accessing and modifying rows of a result set one by one. This mechanism is necessary when the database is accessed from an external application program. The JDBC ResultSet interface allows this method of access from Java programs and is supported by HyperSQL.

HyperSQL supports this method of returning single or multiple result sets from SQL/PSM procedures only via the JDBC CallableStatement interface. Cursors are declared and opened within the body of the procedure. No further operation is performed on the cursors within the procedure. When the execution of the procedure is complete, the cursors become available as Java ResultSet objects via the CallableStatement instance that called the SQL/PSM procedure.

The JDBC CallableStatement class is used with the SQL statement CALL <routine name> ( <argument 1>, ... ) to call procedures (also to call functions). After the call to execute(), the getXXX() methods can be used to retrieve INOUT or OUT arguments after the call. The getMoreResults() method and the getResultSet() method can be used to access the ResultSet(s) returned by a procedure that returns one or more results. If the procedure returns more than one result set, the getMoreResults() call moves to the next result.

In the example below, the procedure inserts a row into the customer table. It then performs the SELECT statement to return the latest inserted row as a result set. Therefore, the definition includes the DYNAMIC RESULT SETS 1 clause. You must specify correctly the maximum number of result sets that the procedure may return.

 CREATE PROCEDURE new_customer(firstname VARCHAR(50), lastname VARCHAR(50))
   MODIFIES SQL DATA DYNAMIC RESULT SETS 1
   BEGIN ATOMIC
     DECLARE result CURSOR FOR SELECT * FROM CUSTOMERS WHERE ID = IDENTITY();
     INSERT INTO CUSTOMERS VALUES (DEFAULT, firstname, lastname, CURRENT_TIMESTAMP);
     OPEN result;    
   END

The above procedure is called in Java using a CallableStatement

 Connection conn = ...;
 CallableStatement call = conn.prepareCall("call new_customer(?, ?)");
 call.setString(1, "Paul");
 call.setString(2, "Smith");
 call.execute();
 if (call.getMoreResults()) // optional
     ResultSet result = call.getResultSet();

Alternatively,

 Connection conn = ...;
 CallableStatement call = conn.prepareCall("call new_customer(?, ?)");
 call.setString(1, "Paul");
 call.setString(2, "Smith");
 call.execute();
 ResultSet result = call.getResultSet();

Or in this case, where there is no OUT or INOUT parameter to be accessed after the call, executeQuery() can be called

 Connection conn = ...;
 CallableStatement call = conn.prepareCall("call new_customer(?, ?)");
 call.setString(1, "Paul");
 call.setString(2, "Smith");
 ResultSet result = call.executeQuery();

In the example below a procedure has one IN argument and two OUT arguments. The JDBC CallableStatement is used to retrieve the values returned in the OUT arguments.

 CREATE PROCEDURE get_customer(IN p_id INT, OUT p_firstname VARCHAR(50), OUT p_lastname VARCHAR(50)) 
   READS SQL DATA
   BEGIN ATOMIC
     -- this statement uses the p_id to get firstname and lastname
     SELECT firstname, lastname INTO p_firstname, p_lastname FROM customers WHERE id = p_id;
   END

 Connection conn = ...;
 CallableStatement call = conn.prepareCall("call get_customer(?, ?, ?)");
 call.setInt(1, 121); // only the IN (or INOUT) arguments should be set before the call
 call.execute();
 String firstname = call.getString(2); // the OUT (or INOUT) arguments are retrieved after the call
 String lastname = call.getString(3);

SQL/JRT procedures are discussed in the Java Language Procedures section below. Those routines are called exactly the same way as SQL/PSM procedures, using the JDBC CallableStatement interface.

It is also possible to use a JDBC Statement or PreparedStatement object to call a procedure if the procedure arguments are constant. If the procedure returns one or more result sets, the Statement.getMoreResults() method should be called before retrieving the ResultSet.

An SQL/JRT or SQL/PSM function (as opposed to procedure) returns either a value or a table in a ResultSet. Functions are called from JDBC similar to procedures, but with functions, the getMoreResuls() method should not be called at all. The getResulSet() method is called after calling the execute() method.

Recursive Routines

Routines can be recursive. Recursive functions are often functions that return arrays or tables. To create a recursive routine, the routine definition must be created first with a dummy body. Then the ALTER ROUTINE statement is used to define the routine body.

In the example below, the table contains a tree of rows each with a parent. The routine returns an array containing the id list of all the direct and indirect children of the given parent. The routine appends the array variable id_list with the id of each direct child and for each child appends the array with the id array of its children by calling the routine recursively.

The routine can be used in a SELECT statement as the example shows.

 CREATE TABLE ptree (pid INT, id INT);
 INSERT INTO ptree VALUES (NULL, 1) ,(1,2), (1,3),(2,4),(4,5),(3,6),(3,7);

 -- the function is created and always throws an exception when used
 CREATE FUNCTION child_arr(p_pid INT) RETURNS INT ARRAY
   SPECIFIC child_arr_one
   READS SQL DATA
   SIGNAL SQLSTATE '45000'

 -- the actual body of the function is defined, replacing the statement that throws the exception
 ALTER SPECIFIC ROUTINE child_arr_one
   BEGIN ATOMIC
     DECLARE id_list INT ARRAY DEFAULT ARRAY[];
     for_loop:
     FOR SELECT id FROM ptree WHERE pid = p_pid DO
       SET id_list[CARDINALITY(id_list) + 1] = id;
       SET id_list = id_list || child_arr(id);
     END FOR for_loop;
     RETURN id_list;
   END

 -- the function can now be used in SQL statements
 SELECT * FROM TABLE(child_arr(2))

In the next example, a table with two columns is returned instead of an array. In this example, a local table variable is declared and filled with the children and the children's children.

 CREATE FUNCTION child_table(p_pid INT) RETURNS TABLE(r_pid INT, r_id INT)
   SPECIFIC child_table_one
   READS SQL DATA
   SIGNAL SQLSTATE '45000'

 ALTER SPECIFIC ROUTINE child_table_one
   BEGIN ATOMIC
     DECLARE TABLE child_tree (pid INT, id INT);
     for_loop:
     FOR SELECT pid, id FROM ptree WHERE pid = p_pid DO
       INSERT INTO child_tree VALUES pid, id;
       INSERT INTO child_tree SELECT r_pid, r_id FROM TABLE(child_table(id));
     END FOR for_loop;
     RETURN TABLE(SELECT * FROM child_tree);
   END

-- the function can now be used in SQL statements
 SELECT * FROM TABLE(child_table(1))

Infinite recursion is not possible as the routine is terminated when a given depth is reached.

Java Language Routines (SQL/JRT)

The general features of SQL-Invoked Routines are shared between PSM and JRT routines. These features are covered in the previous section. This section deals with specific aspects of JRT routines.

The body of a Java language routine is a static method of a Java class, specified with a fully qualified method name in the routine definition. A simple CREATE FUNCTION example is given below, which defines the function to call the java.lang.Math.sinh(double d) Java method. The function can be called in SQL statements just like any built-in function.

 CREATE FUNCTION sinh(v DOUBLE) RETURNS DOUBLE
   LANGUAGE JAVA DETERMINISTIC NO SQL
   EXTERNAL NAME 'CLASSPATH:java.lang.Math.sinh'

 SELECT sinh(doublecolumn) FROM mytable

In the example below, the static method named toZeroPaddedString is specified to be called when the function is invoked.

 CREATE FUNCTION zero_pad(x BIGINT, digits INT, maxsize INT)
   RETURNS CHAR VARYING(100)
   LANGUAGE JAVA DETERMINISTIC NO SQL
   EXTERNAL NAME 'CLASSPATH:org.hsqldb.lib.StringUtil.toZeroPaddedString'

The signature of the Java method (used in the Java code but not in SQL code to create the function) is given below:

 public static String toZeroPaddedString(long value, int precision, int maxSize)

The parameter and return types of the SQL routine definition must match those of the Java method according to the table below:

SMALLINT

short or Short

INT

int or Integer

BIGINT

long or Long

NUMERIC or DECIMAL

BigDecimal

FLOAT or DOUBLE

double or Double

CHAR or VARCHAR

String

DATE

java.sql.Date

TIME

java.sql.Time

TIME WITH TIME ZONEjava.time.OffsetTime

TIMESTAMP

java.sql.Timestamp

TIMESTAMP WITH TIME ZONEjava.time.OffsetDateTime
INTERVAL MONTHjava.time.Period
INTERVAL SECONDjava.time.Duration

BINARY

byte[]

VARBINARYbyte[]

BOOLEAN

boolean or Boolean

ARRAY of any typejava.sql.Array

TABLE

java.sql.ResultSet

For OUT and INOUT parameters of procedures Java arrays of the type given in the table above should be used as parameters For example if the OUT parameter is defined as VARCHAR(10), it matches a Java parameter type defined as String[].

If the specified Java method is not found or its parameters and return types do not match the definition, an exception is raised. If more than one version of the Java method exists, then the one with matching parameter and return types is found and registered. If two “equivalent” methods exist, the first one is registered. (This situation arises only when a parameter is a primitive in one version and an Object in another version, e.g. long and java.lang.Long.).

When the Java method of an SQL/JRT routine returns a value, it should be within the size and precision limits defined in the return type of the SQL-invoked routine, otherwise an exception is raised. Any difference in numeric scale is ignored and corrected. For example, in the above example, the RETURNS CHAR VARYING(100) clause limits the length of the strings returned from the Java method to 100. But if the number of digits after the decimal point (scale) of a returned BigDecimal value is larger than the scale specified in the RETURNS clause, the decimal fraction is silently truncated and no exception of warning is raised.

When the function is specified as RETURNS TABLE(...) the static Java method should return a java.sql.ResultSet object. For an example of how to construct a org.hsqldb.jdbc.JDBCResultSet for this purpose, see the source code for the org.hsqldb.jdbc.JDBCArray class. At the time of invocation, the Java method is called and the returned ResultSet is transformed into an SQL table. The column types of the declared TABLE must match those of the ResultSet, otherwise an exception is raised at the time of invocation.

Polymorphism

If two versions of the same SQL invoked routine with different parameter types are required, they can be defined to point to the same method name or different method names, or even methods in different classes. In the example below, the first two definitions refer to the same method name in the same class. In the Java class, the two static methods are defined with corresponding method signatures.

In the third example, the Java function returns a result set and the SQL declaration includes RETURNS TABLE.

 CREATE FUNCTION an_hour_before_or_now(t TIME)
   RETURNS TIME
   NO SQL
   LANGUAGE JAVA PARAMETER STYLE JAVA
   EXTERNAL NAME 'CLASSPATH:org.npo.lib.nowLessAnHour'

 CREATE FUNCTION an_hour_before_or_now(t TIMESTAMP)
   RETURNS TIMESTAMP
   NO SQL
   LANGUAGE JAVA PARAMETER STYLE JAVA
   EXTERNAL NAME 'CLASSPATH:org.npo.lib.nowLessAnHour'

 CREATE FUNCTION testquery(i INTEGER) 
   RETURNS TABLE(n VARCHAR(20), i INT) 
   READS SQL DATA
   LANGUAGE JAVA
   EXTERNAL NAME 'CLASSPATH:org.hsqldb.test.TestJavaFunctions.getQueryResult'

In the Java class the definitions are as follows. Note the definition of the getQueryResult() method begins with a java.sql.Connection parameter. This parameter is ignored when choosing the Java method. The parameter is used to pass the current JDBC connection to the Java method.

 public static java.sql.Time nowLessAnHour(java.sql.Time value) {
     ...
 }

 public static java.sql.Timestamp nowLessAnHour(java.sql.Timestamp value)
     ...
 }

 public static ResultSet getQueryResult(Connection connection, int i) throws SQLException {
     Statement st = connection.createStatement();
     return st.executeQuery("SELECT * FROM T WHERE I < " + i);
 }

Java Language Procedures

Java procedures are defined in a similar way to functions. The differences are:

  • The return type of the Java static method must be void.

  • If a parameter is defined as OUT or INOUT, the corresponding Java static method parameter must be defined as an array of the JDBC non-primitive type.

  • When the Java static method is invoked, the OUT and INOUT arguments are passed to the Java method as a single-element array.

  • The static method can modify the OUT or INOUT argument by assigning a value to the sole element of the argument array.

  • A procedure can return one or more result sets. These are instantiated as JDBC ResultSet objects by the Java static method and returned in the array arguments of the method. The signature of the Java method for a procedure that has N declared parameters and returns M result sets has the following pattern. The N parameters corresponding to the signature of the declared SQL procedure come first, followed by M parameters as ResultSet arrays.

    When the SQL procedure is executed, the Java method is called with single-element array arguments passed for OUT and INOUT SQL parameters, and single-element arrays of ResultSet for the returned ResultSet objects. The Java method may call the execute() or executeQuery() methods of JDBC Statement or PreparedStatement objects that are declared within the method and assign the ResultSet objects to the first element of each ResultSet[] argument. For the returned ResultSet objects, the Java method should not call the methods of java.sql.ResultSet before returning.

    void methodName(<arg1>, ... <argN>, ResultSet[] r1, ..., ResultSet[] rM)

  • If the procedure contains SQL statements, only statements for data access and manipulation are allowed. The Java method should not perform commit or rollback. The SQL statements should not change the session settings and should not include statements that create or alter tables or other database objects. These rules are generally enforced by the engine, but additional enforcement may be added in future versions

An example of a procedure definition, together with its Java signature, is given below. This procedure is the SQL/JRT version of the example discussed above for SQL/PSM.

 CREATE PROCEDURE get_customer(IN id INT, OUT firstname VARCHAR(50), OUT lastname VARCHAR(50)) 
   READS SQL DATA
   LANGUAGE JAVA
   EXTERNAL NAME 'CLASSPATH:org.hsqldb.test.Test01.getCustomerProcedure'

   public static void getCustomerProcedure(int id, String[] firstn, String[] lastn)
       throws java.sql.SQLException {
       // java code here defines String variables somevalue and othervalue
       ...
       firstn[0] = somevalue;  // parameter out value is assigned
       lastn[0] = othervalue;   // parameter out value is assigned
   }

In the next example a procedure is defined to return a result set. The signature of the Java method is also given. The Java method assigns a ResultSet object to the zero element of the ResultSet[] array parameter. The result parameter is always the last one and is declared after the normal IN and OUT parameters.

 CREATE PROCEDURE new_customer(firstname VARCHAR(50), lastname VARCHAR(50))
   MODIFIES SQL DATA 
   LANGUAGE JAVA
   DYNAMIC RESULT SETS 1
   EXTERNAL NAME 'CLASSPATH:org.hsqldb.test.Test01.newCustomerProcedure'

   public static void newCustomerProcedure(String firstn, String lastn,
                       ResultSet[] result) throws java.sql.SQLException {
       // java code here creates a statement
       Connection conn =
           DriverManager.getConnection("jdbc:default:connection");
       Statement statement = conn.createStatement();
       String queryString = "select a, b from ..."; // SQL statement
       ResultSet resultset = statement.executeQuery(queryString);
       result[0] = resultset;  // dynamic result set is assigned
   }

You may want to return your own data in the ResultSet that is returned from an SQL/JRT procedure or function. The org.hsqldb.jdbc.JDBCResultSet has two static factory methods that return instances of the JDBCResultSetBasic class. Refer to the source code to see how you can use this class in your Java static methods. You can use the org.hsqldb.jdbc.JDBCArrayBasic class to create a JDBC Array in your Java static method. This class also includes code to construct a JDBCResultSetBasic instance.

Java language procedures SQL/JRT are used in an identical manner to SQL/PSM routines. See the section under SQL/PSM routines, Returning Data From Procedures, on how to use the JDBC CallableStatement interface to call the procedure and to get the OUT and INOUT arguments and to use the ResultSet objects returned by the procedure.

Java Static Methods

The static methods that are used for procedures and functions must be declared in a public class. The methods must be declared as public static. For functions, the method return type must be one of the JDBC supported types. The IN parameters of the method must be declared as one of the supported types. The OUT and INOUT parameters must be declared as Java arrays of supported types. If the SQL definition of a function includes RETURNS NULL ON NULL INPUT, then the IN parameters of the Java static function can be int or long primitives, otherwise, they must be Integer or Long. The declared Java arrays for OUT and INOUT parameters for SQL INTEGER or BIGINT must be Integer[] or Long[] respectively.

If the SQL definition of the routine includes NO SQL, then no JDBC method call is allowed to execute in the method body. Otherwise, a JDBC Connection can be used within the Java method to access the database. If the definition includes CONTAINS SQL, then no table data can be read. If the definition includes READS SQL DATA, then no table data can be modified. If the definition includes MODIFIES SQL DATA, then data can be modified. In all modes, it is not allowed to execute DDL statements that change the schema definition.

It is possible to use the SQL statement, DECLARE LOCAL TEMPORARY TABLE in a Java method, as this is in the session scope.

There are two ways to use the JDBC Connection object.

  1. Define the Java method with a Connection parameter as the first parameter. This parameter is "hidden" and only visible to the engine. The rest of the parameters, if any, are used to choose the method according to the required types of parameters.

  2. Use the SQL/JRT Standard "jdbc:default:connection" method. With this approach, the Java method does not include a Connection parameter. In the method body, the connection is established with a method call to DriverManager, as in the example below:

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

Both methods return a connection that is based on the current session. This connection has some extra properties, for example, the Close() method does not actually close it.

An example of an SQL PROCEDURE with its Java method definition is given below. The CREATE PROCEDURE statement is the same with or without the Connection parameter:

 CREATE PROCEDURE proc1(IN P1 INT, IN P2 INT, OUT P3 INT)
 SPECIFIC P2 LANGUAGE JAVA DETERMINISTIC MODIFIES SQL DATA EXTERNAL NAME 'CLASSPATH:org.hsqldb.test.TestStoredProcedure.procTest2'");

In the first example, the "jdbc:default:connection" method is used. In the second example, a connection parameter is used

 public static void procTest2(int p1, int p2,
                    Integer[] p3) throws java.sql.SQLException {

     Connection conn =
         DriverManager.getConnection("jdbc:default:connection");
     java.sql.Statement stmt = conn.createStatement();

     stmt.execute("INSERT INTO MYTABLE VALUES(" + p1 + ",'test1')");
     stmt.execute("INSERT INTO MYTABLE VALUES(" + p2 + ",'test2')");

     java.sql.ResultSet rs = stmt.executeQuery("select * from MYTABLE");
     java.sql.ResultSetMetaData meta = rs.getMetaData();

     int cols  = meta.getColumnCount();
     p3[0] = Integer.valueOf(cols);

     rs.close();
     stmt.close();
 }

//  alternative declaration with Connection parameter
//  public static void procTest2(Connection conn, int p1, int p2,
//                    Integer[] p3) throws java.sql.SQLException {

When the stored procedure is called by the user's program, the value of the OUT parameter can be read after the call.

 // a CallableStatement is used to prepare the call
 // the OUT parameter contains the return value
 CallableStatement c = conn.prepareCall("call proc1(1,2,?)");
 c.execute();
 int value = c.getInt(1);

Legacy Support

The legacy HyperSQL statement, CREATE ALIAS <name> FOR <fully qualified Java method name> is no longer supported directly. It is supported when importing databases and translates to a special CREATE FUNCTION <name> statement that creates the function in the PUBLIC schema.

The direct use of a Java method as a function is still supported but deprecated. It is internally translated to a special CREATE FUNCTION statement where the name of the function is the double quoted, fully qualified name of the Java method used.

Securing Access to Classes and Routines

The static methods of any class that is on the classpath can be made available to be used. From version 2.7.1 access is not allowed by default. The optional Java system property hsqldb.method_class_names allows access to classes other than java.lang.Math by specifying a semicolon-separated list of allowed packages, classes, or methods. A property value that ends with .* is treated as a wild card and allows access to all class or method names formed by substitution of the * (asterisk).

In the example below, the property has been included as an argument to the Java command.

 java -Dhsqldb.method_class_names="org.me.MyClass.myMethod;org.you.YourClass.*;org.you.lib.*" [the rest of the command line]

The above example allows access to the method org.me.MyClass.myMethod and all methods in the class org.you.YourClass together with all the classes in the org.you.lib package. Note that if the property is not defined, no access is allowed.

The user who creates a Java routine must have the relevant access privileges on the tables that are used inside the Java method.

Once the routine has been defined, the normal database access control applies to its user. The routine can be executed only by those users who have been granted EXECUTE privileges on it. Access to routines can be granted to users with GRANT EXECUTE or GRANT ALL. For example, GRANT EXECUTE ON myroutine TO PUBLIC.

Warning

The definition of SQL/JRT routines referencing the user's Java static methods is stored in the .script file of the database.

If the database is opened in a Java environment that does not have access to the referenced Java static methods on its classpath, the SQL/JRT routines are not created when the database is opened. When the database is closed, the routine definitions are lost.

There is a workaround to prevent opening the database when the static methods are not on the classpath. You can create an SQL/PSM procedure which calls all the SQL/JRT functions and procedures in your database. The calls should have the necessary dummy arguments. This procedure will fail to be created when the referenced methods are not accessible and will return "Error in script file". There is no need ever to execute the procedure. However, to avoid accidental use, you can ensure that it does not execute the SQL/JRT routines by adding a line such as IF TRUE THEN SIGNAL SQLSTATE '45000'; before any references to the SQL/JRT routines.

User-Defined Aggregate Functions

HyperSQL adds an extension to the SQL Standard to allow user-defined aggregate functions. A user-defined aggregate function has a single parameter when it is used in SQL statements. Unlike the predefined aggregate functions, the keyword DISTINCT cannot be used when a user-defined aggregate function is invoked. Like all user-defined functions, an aggregate function belongs to a schema and can be polymorphic (with multiple function definitions with the same name but different parameter types).

A user-defined aggregate function can be used in SQL statements where a predefined aggregate function is allowed.

Definition of Aggregate Functions

An aggregate function is always defined with 4 parameters. The first parameter is the parameter that is used when the function is invoked in SQL statements, the rest of the parameter are invisible to the invoking SQL statement. The type of the first parameter is user defined. The type of the second parameter must be BOOLEAN. The third and fourth parameters have user-defined types and must be defined as INOUT parameters. The defined return type of the function determines the type of the value returned when the function is invoked.

CREATE AGGREGATE FUNCTION

user defined aggregate function definition

Aggregate function definition is similar to normal function definition and has the mandatory <returns clause>. The BNF is given below.

<user defined aggregate function> ::= CREATE AGGREGATE FUNCTION <schema qualified routine name> <SQL aggregate parameter declaration list> <returns clause> <routine characteristics> <routine body>

The parameter declaration list BNF is given below. The type of the first parameter is used when the function is invoked as part of an SQL statement. When multiple versions of a function are required, each version will have the first parameter of a different type.

<SQL aggregate declaration list> ::= <left paren> [IN] [ <SQL parameter name> ] <parameter type> <comma> [IN] [ <SQL parameter name> ] BOOLEAN <comma> INOUT [ <SQL parameter name> ] <parameter type> <comma> INOUT [ <SQL parameter name> ] <parameter type> <right paren>

The return type is user defined. This is the type of the resulting value when the function is called. Usually an aggregate function is defined with CONTAINS SQL, as it normally does not read the data in database tables, but it is possible to define the function with READS SQL DATA and access the database tables.

When a SQL statement that uses the aggregate function is executed, HyperSQL invokes the aggregate function, with all the arguments set, once per each row in order to compute the values. Finally, it invokes the function once more to return the final result.

In the computation phase, the first argument is the value of the user argument as specified in the SQL statement, computed for the current row. The second argument is the boolean FALSE. The third and fourth argument values can have any type and are initially null, but they can be updated in the body of the function during each invocation. The third and fourth arguments act as registers and hold their values between invocations. The return value of the function is ignored during the computation phase (when the second parameter is FALSE).

After the computation phase, the function is invoked once more to get the final result. In this invocation, the first argument is NULL and the second argument is boolean TRUE. The third and fourth arguments hold the values they held at the end of the last invocation. The value returned by the function in this invocation is used as the result of the aggregate function computation in the invoking SQL statement. In SQL queries with GROUP BY, the call sequence is repeated separately for each separate group.

SQL PSM Aggregate Functions

The example below features a user-defined version of the Standard AVG(<value expression>) aggregate function for INTEGER input and output types. This function behaves differently from the Standard AVG function as it returns 0 when all the input values are null. In the computation phase, each aggregated value X is added to the ADDUP argument and the COUNTER argument is incremented. When the computation is complete, the function is called with FLAG set to TRUE to get the result of the computation, which is ADDUP divided by COUNTER.

 CREATE AGGREGATE FUNCTION udavg(IN x INTEGER, IN flag BOOLEAN, INOUT addup BIGINT, INOUT counter INT)
   RETURNS INTEGER
   CONTAINS SQL
   BEGIN ATOMIC
     IF flag THEN
       RETURN addup / counter;
     ELSE
       SET counter = COALESCE(counter, 0) + 1;
       SET addup = COALESCE(addup, 0) + COALESCE(x, 0);
       RETURN NULL;
     END IF;
   END

The user-defined aggregate function is used in a select statement in the example below. Only the first parameter is visible and utilised in the select statement.

 SELECT udavg(id) FROM customers GROUP BY lastname;

In the example below, the function returns an array that contains all the values passed for the aggregated column. The first iteration creates an array with the first value, which is appended with a new value in each iteration. For use with longer arrays, you can optimise the function by defining a larger array in the first iteration, and using the TRIM_ARRAY function on the RETURN to cut the array to size. This function is similar to the built-in ARRAY_AGG function

 CREATE AGGREGATE FUNCTION array_aggregate(IN val VARCHAR(100), IN flag boolean, INOUT buffer VARCHAR(100) ARRAY, INOUT counter INT)
   RETURNS VARCHAR(100) ARRAY
   CONTAINS SQL
   BEGIN ATOMIC
     IF flag THEN
       RETURN buffer;
     ELSE
       IF val IS NULL THEN RETURN NULL; END IF;
       IF counter IS NULL THEN SET counter = 0; END IF;
       SET counter = counter + 1;
       IF counter = 1 THEN SET buffer = ARRAY[val];
       ELSE SET buffer[counter] = val; END IF;
       RETURN NULL;
     END IF;
   END

The tables and data for the select statement below are created with the DatabaseManager or DatabaseManagerSwing GUI apps. (You can find the SQL in the TestSelf.txt file in the zip). Part of the output is shown. Each row of the output includes an array containing the values for the invoices for each customer.

 SELECT ID, FIRSTNAME, LASTNAME, ARRAY_AGGREGATE(CAST(INVOICE.TOTAL AS VARCHAR(100))) 
   FROM customer JOIN INVOICE ON ID =CUSTOMERID
   GROUP BY ID, FIRSTNAME, LASTNAME

 11 Susanne   Karsen    ARRAY['3988.20']                               
 12 John      Peterson  ARRAY['2903.10','4382.10','4139.70','3316.50'] 
 13 Michael   Clancy    ARRAY['6525.30']                               
 14 James     King      ARRAY['3665.40','905.10','498.00']             
 18 Sylvia    Clancy    ARRAY['634.20','4883.10']                      
 20 Bob       Clancy    ARRAY['3414.60','744.60']

In the example below, the function returns a string that contains the comma-separated list of all the values passed for the aggregated column. This function is similar to the built-in GROUP_CONCAT function.

 CREATE AGGREGATE FUNCTION group_concatenate
     (IN val VARCHAR(100), IN flag BOOLEAN, INOUT buffer VARCHAR(1000), INOUT counter INT)
     RETURNS VARCHAR(1000)
     CONTAINS SQL
   BEGIN ATOMIC
     IF FLAG THEN
       RETURN BUFFER;
     ELSE
       IF val IS NULL THEN RETURN NULL; END IF;
       IF buffer IS NULL THEN SET BUFFER = ''; END IF;
       IF counter IS NULL THEN SET COUNTER = 0; END IF;
       IF counter > 0 THEN SET buffer = buffer || ','; END IF;
       SET buffer = buffer + val;
       SET counter = counter + 1;
       RETURN NULL;
     END IF;
   END

The same tables and data as for the previous example is used. Part of the output is shown. Each row of the output is a comma-separated list of names.

 SELECT group_concatenate(firstname || ' ' || lastname) FROM customer GROUP BY lastname
  
 Laura Steel,John Steel,John Steel,Robert Steel                                   
 Robert King,Robert King,James King,George King,Julia King,George King            
 Robert Sommer,Janet Sommer                                                       
 Michael Smith,Anne Smith,Andrew Smith                                            
 Bill Fuller,Anne Fuller                                                          
 Laura White,Sylvia White                                                         
 Susanne Clancy,Michael Clancy,Sylvia Clancy,Bob Clancy,Susanne Clancy,John Clancy

Java Aggregate Functions

A Java aggregate function is defined in a similar way to PSM functions, apart from the routine body, which is defined as EXTERNAL NAME ... The Java function signature must follow the rules for both nullable and INOUT parameters, therefore:

No argument is defined as a primitive or primitive array type. This allows nulls to be passed to the function. The second and third arguments must be defined as arrays of the JDBC non-primitive types listed in the table in the previous section.

In the example below, a user-defined aggregate function for geometric mean is defined.

 CREATE AGGREGATE FUNCTION geometric_mean(IN val DOUBLE, IN flag BOOLEAN, INOUT register DOUBLE, INOUT counter INT)
     RETURNS DOUBLE
     NO SQL
     LANGUAGE JAVA
     EXTERNAL NAME 'CLASSPATH:org.hsqldb.test.Test01.geometricMean'

The Java function definition is given below:

 public static Double geometricMean(Double in, Boolean flag,
         Double[] register, Integer[] counter) {
     if (flag) {
         if (register[0] == null) { return null; }
         double a = register[0].doubleValue();
         double b = 1 / (double) counter[0];
         return Double.valueOf(java.lang.Math.pow(a, b));
     }
     if (in == null) { return null; }
     if (in.doubleValue() == 0) { return null; }
     if (register[0] == null) {
         register[0] = in;
         counter[0]  = Integer.valueOf(1);
     } else {
         register[0] = Double.valueOf(register[0].doubleValue() * in.doubleValue());
         counter[0] = Integer.valueOf(counter[0].intValue() + 1);
     }
     return null;
 }

In a select statement, the function is used exactly like the built-in aggregate functions:

 SELECT geometric_mean(age) FROM  FROM customer

$Revision: 6787 $