Are you aware of the fenced and deterministic attributes?
SQL user-defined functions (UDFs) have been available since OS/400 V4R4. UDFs provide a great tool for allowing you to easily perform a business calculation as an SQL query, processing a set of rows in your database. If you want an explanation of how to implement UDFs, take a look at the IBM Redbook Stored Procedures, Triggers, and User-Defined Functions on DB2 UDB for iSeries.
For those of you already familiar with UDFs, you need to be aware that two attributes can be used to improve UDF performance. Knowledge of these two attributes is particularly important because these attributes default to the slower-performing values if they are not specified as part of your function definition.
Fenced
The first is the fenced or not fenced attribute. Fenced is the default attribute and is primarily supported because DB2 products other than those for iSeries need the option to control their memory usage during UDF execution. (This aspect does not apply to DB2 UDB for iSeries since the database engine is part of the operating system.)
The fenced attribute causes the UDF to perform more slowly because it causes DB2 to perform UDF calls in a different thread. Starting with V5R2, the not fenced attribute allows DB2 to execute the UDF call within the same thread as the invoking SQL statement. This ability to call the UDF within the same thread is supported only when the SQL Query Engine (SQE) processes the invoking SQL statement.
Here's a simple example of a UDF, getCelsius, which converts Fahrenheit temperatures to Celsius. It specifies the not fenced attribute to improve performance:
RETURNS DECIMAL(4,0)
LANGUAGE SQL
DETERMINISTIC
NOT FENCED
BEGIN
RETURN( CEILING( (5*(fahrenheit_temp-32) )/9) );
END;
Deterministic
Deterministic is the other setting on the getCelsius function definition that can help improve performance. The deterministic setting says that the UDF will always return the same result value when called with the exact same input parameters. For example, this getCelsius function is deterministic because each time it's invoked with an input parameter value of 32, it will output a Celsius temperature value of 0. Every time this deterministic getCelsius UDF is given a value of 50, it will return a value of 10 to the invoker.
Contrast that with the GetLocalTemp UDF below, which is a non-deterministic function. This function receives a ZIP code value as input and then passes this value on a call to an external stored procedure. The AccessLocalTemp reads an XML file to find the current temperature for the specified ZIP code and returns that temperature value to the UDF. This XML file is updated every five minutes via RSS or an FTP process. The GetLocalTemp UDF is declared as non-deterministic because passing in the same ZIP code on successive calls is not guaranteed to return the same output value. The temperature value for a ZIP code value of 51106 could return 35 on the first invocation and 36 on the next invocation.
RETURNS INTEGER
NOT DETERMINISTIC
NOT FENCED
LANGUAGE SQL
BEGIN
DECLARE localTemp INT;
CALL AccessLocalTemp(zipcode,localTemp);
RETURN localTemp;
END;
You should now have a firm understanding of deterministic functions, but it may be unclear how this setting can improve performance. The main performance benefit of deterministic functions is that they allow DB2 UDB to cache the input parameter values and the return value for a UDF call. On successive calls to that UDF with the same input parameters, DB2 UDB can just return the cached returned value without ever invoking the UDF. Performance is gained by eliminating the overhead involved with calling the UDF. Remember that when DB2 UDB invokes a UDF, it's equivalent to the performance of executing an unbound, external program call; thus, avoiding the call can produce noticeable performance gains.
The following query provides a very common example of how UDFs perform some user-defined calculation. Just consider how many low temperature values over 365 days share the same value, which can allow DB2 UDB to skip calling the function and use its cache instead.
This caching of deterministic function calls was first added in V5R3 and is again only possible when SQE processes the invoking SQL statement.
Kent Milligan is a DB2 UDB Technology Specialist on IBM's eServer Solutions Enablement team. He spent the first seven years at IBM as a member of the DB2 development team in Rochester. He can be reached at
LATEST COMMENTS
MC Press Online