1 Exception message with null values

A raise exception message with null value variables will print an empty message:

Copy
CREATE PROCEDURE test_raise_msg() 
    
    DEFINE m_str char(10);
    LET m_str  = NULL;
    RAISE EXCEPTION -746, 0, 'Start ' || m_str || ' end';
END PROCEDURE;
EXECUTE PROCEDURE test_raise_msg()
java.sql.SQLException:

The avoid this it´s necessary to use NVL function in null variables:

Copy
CREATE PROCEDURE test_raise_msg() 
    
    DEFINE m_str char(10);
    LET m_str  = NULL;
    RAISE EXCEPTION -746, 0, 'Start ' || NVL(m_str, 'body') || ' end';
END PROCEDURE;
EXECUTE PROCEDURE test_raise_msg()
java.sql.SQLException: Start body end

2 Procedures in a WHERE clause

Consider the following SPL defining a method that returns a list of customer IDs for all customers with a given address:

Copy
CREATE FUNCTION get_customer_from_address(p_addr varchar(255)) 
    RETURNING SET(INTEGER NOT NULL);
    
    DEFINE GLOBAL m_customer_id       INTEGER DEFAULT 0;
    DEFINE m_customer_list SET(INTEGER NOT NULL);

    select c_custkey 
      into m_customer_id
      from customer 
     where c_address = p_addr;

    INSERT INTO TABLE(m_customer_list) VALUES (m_customer_id);

	RETURN m_customer_list;
END FUNCTION;

The following SQL statement, which uses the previous routine, can be used to get all the data for the customers with a particular address:

Copy
select * 
  from customer 
 where c_custkey IN get_customer_from_address('Hp8GyFQgGHFYSilH5tBfe');

When there are a lot of rows, the statement above can take long time... This happend because the procedure is executed for each row, even no row values are used as parameters.

The query performance can be improved by using the list of customer IDs in the FROM clause (as a joined table):

Copy
select * 
  from customer, 
       table(get_customer_from_address('Hp8GyFQgGHFYSilH5tBfe')) as list(customerid) 
 where c_custkey = list.customerid;

3 Returning SET(s)

An SPL function can return a SET or MULTISET

Copy
CREATE FUNCTION collection_test() RETURNING MULTISET(LVARCHAR NOT NULL);
    DEFINE set_value SET(LVARCHAR NOT NULL);
    DEFINE return_value MULTISET(LVARCHAR NOT NULL);
    
    INSERT INTO TABLE(set_value) VALUES("w");
    INSERT INTO TABLE(set_value) VALUES("x");
    INSERT INTO TABLE(set_value) VALUES("v");
    
    INSERT INTO TABLE(return_value) SELECT * FROM TABLE(set_value);
    
    RETURN return_value;
END FUNCTION;

SELECT collection_test() FROM TABLE(MULTISET{1});