Example: Cast between UDTs

Suppose you want to define a UDF that converts Canadian dollars to U.S. dollars.

Suppose you can obtain the current exchange rate from a file managed outside of DB2®. Then define a UDF that obtains a value in Canadian dollars, accesses the exchange rate file and returns the corresponding amount in U.S. dollars.

At first glance, such a UDF may appear easy to write. However, not all C compilers support DECIMAL values. The UDTs representing different currencies have been defined as DECIMAL. Your UDF will need to receive and return DOUBLE values, since this is the only data type provided by C that allows the representation of a DECIMAL value without losing the decimal precision. Your UDF should be defined as follows:

     CREATE FUNCTION CDN_TO_US_DOUBLE(DOUBLE) RETURNS DOUBLE 
       EXTERNAL NAME 'MYLIB/CURRENCIES(C_CDN_US)' 
       LANGUAGE C 
       PARAMETER STYLE DB2SQL 
       NO SQL 
       NOT DETERMINISTIC

The exchange rate between Canadian and U.S. dollars may change between two invocations of the UDF, so you declare it as NOT DETERMINISTIC.

The question now is, how do you pass Canadian dollars to this UDF and get U.S. dollars from it? The Canadian dollars must be cast to DECIMAL values. The DECIMAL values must be cast to DOUBLE. You also need to have the returned DOUBLE value cast to DECIMAL and the DECIMAL value cast to U.S. dollars.

Such casts are performed automatically by DB2 anytime you define sourced UDFs, whose parameter and return type do not exactly match the parameter and return type of the source function. Therefore, you need to define two sourced UDFs. The first brings the DOUBLE values to a DECIMAL representation. The second brings the DECIMAL values to the UDT. Define the following:

     CREATE FUNCTION CDN_TO_US_DEC (DECIMAL(9,2)) RETURNS DECIMAL(9,2) 
       SOURCE CDN_TO_US_DOUBLE (DOUBLE) 
  
     CREATE FUNCTION US_DOLLAR (CANADIAN_DOLLAR) RETURNS US_DOLLAR 
       SOURCE CDN_TO_US_DEC (DECIMAL())

Note that an invocation of the US_DOLLAR function as in US_DOLLAR(C1), where C1 is a column whose type is Canadian dollars, has the same effect as invoking:

    US_DOLLAR (DECIMAL(CDN_TO_US_DOUBLE (DOUBLE (DECIMAL (C1)))))

That is, C1 (in Canadian dollars) is cast to decimal which in turn is cast to a double value that is passed to the CDN_TO_US_DOUBLE function. This function accesses the exchange rate file and returns a double value (representing the amount in U.S. dollars) that is cast to decimal, and then to U.S. dollars.

A function to convert Euros to U.S. dollars is similar to the example above:

     CREATE FUNCTION EURO_TO_US_DOUBLE(DOUBLE) 
       RETURNS DOUBLE 
       EXTERNAL NAME 'MYLIB/CURRENCIES(C_EURO_US)'
       LANGUAGE C 
       PARAMETER STYLE DB2SQL 
       NO SQL 
       NOT DETERMINISTIC
       
     CREATE FUNCTION EURO_TO_US_DEC (DECIMAL(9,2)) 
       RETURNS DECIMAL(9,2) 
       SOURCE EURO_TO_US_DOUBLE(DOUBLE) 
  
     CREATE FUNCTION US_DOLLAR(EURO) RETURNS US_DOLLAR 
       SOURCE EURO_TO_US_DEC (DECIMAL())