In my past two TechTips, I reviewed 11 of the new built-in SQL functions added to the iSeries implementation of DB2 UDB in V5R3. Now, let's take a look at the 14 remaining new functions. I'll break the functions down into groupings based on the type of values handled by the function.
Date Functions
SQL functions can make dealing with date and time values much easier. The DAYNAME function returns a string containing the mixed-case weekday name for the supplied date. The value supplied on the function's single parameter must be a date, timestamp, or character string representation of a date or timestamp value. The following statement is an example of using the DAYNAME function.
FROM SYSIBM.SYSDUMMY1
When executed, this example returns the string "Sunday."
Similarly, the MONTHNAME function returns a mixed-case string containing the month name for the supplied date, timestamp, or string representation of a date or timestamp. The statement below is an example of the MONTHNAME function.
FROM SYSIBM.SYSDUMMY1
When executed this example returns the value "May."
The two functions can be combined to return a "long date format" representation of the date, as shown here.
' ' || DAY(DTEFLD) || ', ' || YEAR(DTEFLD)
AS LongDate
FROM MYLIB.MYFILE
Assuming the value of DTEFLD is a date value representing the date 5/15/2005, this example will return "Sunday, May 15, 2005."
The EXTRACT function retrieves a portion of a specified date, time, or timestamp field. If a date value is specified, valid options for the portion of the time to be retrieved are YEAR, MONTH, and DAY. If a time value is specified, valid options are HOUR, MINUTE, and SECOND. Any of these can be retrieved from a timestamp value. Below are examples of both possible uses of this function.
FROM MYLIB.MYFILE
SELECT EXTRACT(MINUTE FROM MYTIME)
FROM MYLIB.MYFILE
The functionality offered by this function can also be achieved using the YEAR, MONTH, DAY, HOUR, MINUTE, and SECOND built-in functions.
The TIMESTAMP_ISO function returns a timestamp representation of the supplied date, time, or character string representation of a date or time value. The example below illustrates the use of the TIMESTAMP_ISO function with a date value and a time value.
TIMESTAMP_ISO(TIME('11:30:30 '))
FROM SYSIBM.SYSDUMMY1
Because a timestamp value contains date and time values in one field, the TIMESTAMP_ISO function appends zeros for the time portion of the timestamp when a date value is provided, and it uses the CURRENT DATE value for the date portion of the timestamp if the value provided is a time value. In the case of the example here, the statement will return the values "2005-05-15-00.00.00.000000" and
"2005-05-15-11.30.30.000000," respectively, assuming the statement is executed on 5/15/2005.
String Functions
In V5R3, eight functions have been added for manipulating character string values. Some of these functions convert string data into other data types. Others manipulate the data contained within the string.
A binary string is a sequence of bytes containing the string data. Binary strings always use CCSID 65535. The BINARY function converts a supplied string to another format. It returns a fixed-length binary string version of the supplied character string. The first parameter of the BINARY function defines the string to be converted to binary. This parameter can be any character string value or field. An optional second parameter defines the length of the string in bytes. If the length specified is less than the length of the source string provided, characters will be truncated from the right side of the string. The statement below is a sample of the BINARY function.
FROM SYSIBM.SYSDUMMY1
Because the length value provided is less than the length of the source string, the value returned by this statement will be "This is a ."
Similarly, the VARBINARY function returns a varying-length binary representation of the supplied character string. The difference between the fixed-length binary string and a varying-length binary string is that the varying-length binary string does not include trailing blanks, while the fixed-length string does. The VARBINARY function accepts the same two parameters as the BINARY function. Below is a sample of the VARBINARY function.
FROM SYSIBM.SYSDUMMY1
When executed, this statement returns the full string "This is a VARBINARY string." The difference between the two types becomes evident when determining the length of each string.
The statement below uses the OCTET_LENGTH function to retrieve the length in bytes of the same string as fixed-length and varying-length binary values.
OCTET_LENGTH(BINARY('This is a string',30))
FROM SYSIBM.SYSDUMMY1
When executed, this statement returns the length of the supplied string minus trailing blanks for the first column and including trailing blanks for the second. In this case, that results in values of 16 and 30, respectively.
While the value returned by the OCTET_LENGTH function is expressed in bytes, the BIT_LENGTH function allows us to retrieve the length of a supplied string or numeric value in bits. Below is a modified version of the previous statement using the BIT_LENGTH function.
BIT_LENGTH(BINARY('This is a string',30))
FROM SYSIBM.SYSDUMMY1
This time, the results are expressed as bits rather than bytes, resulting in values of 128 and 240, respectively. Note that the values returned by this function are equal to the byte length multiplied by 8.
The INSERT function allows us to create a character string that contains the value from a source string after inserting a specified secondary string value at a defined location. Optionally, we can replace a specified number of characters from the source string. The first parameter defines the source string, while the second parameter defines the starting location for string insertion. The third parameter defines the number of characters from the source string to be replaced. If 0 is specified, no characters from the source string are removed. The fourth parameter identifies the value to be inserted. The statement below, for example, inserts the word "not" in the supplied source string.
FROM SYSIBM.SYSDUMMY1
The result of this statement is the value "I am not a crook." If, however, we changed the number of replacement characters defined on parameter 3 and used a different replacement value as shown below, the results would be somewhat different.
FROM SYSIBM.SYSDUMMY1
The result of this string would be the value "I am crooked!"
Similarly the REPLACE function is used to create a string that contains a manipulated version of a source string. While the INSERT function inserts or replaces characters at a defined location in the source string, REPLACE searches a source string defined on its first parameter for a search string defined on its second parameter and replaces that value with a replacement string defined on the third parameter. Below is a sample of a statement using the REPLACE function.
FROM SYSIBM.SYSDUMMY1
The result of this function is the string "Cherry Pie."
You can also specify a null string as the replacement value to completely remove the search string from source data. The example below illustrates using this function to remove an unwanted character from the source string.
FROM SYSIBM.SYSDUMMY1
In this example, the unwanted comma character will be removed, and the result will be "Orlando."
The REPEAT function allows us to create a string that is a repetition of the string supplied on its first parameter the number of times specified on the second parameter. The statement below illustrates the use of this function to create an indentation effect in the resulting string.
FROM MYLIB.MYFILE
This example uses the REPEAT function to insert a number of decimal point characters based on the value of the field INDNT. This string is concatenated with the value of the field ITEM to create an indented item listing as shown in Figure 1.
Figure 1: Here's the REPEAT function in action. (Click image to enlarge.)
This example shows how a simple bill-of-material structure could be visually illustrated using the REPEAT function.
The RIGHT function operates much the way similar functions work in other languages. This function allows us to extract from the right side of a string supplied on the first parameter a number of characters specified on the second parameter. The statement below is a sample of using the RIGHT function.
FROM MYLIB.ADDRESSES
This example illustrates the use of the RIGHT function to extract the two rightmost characters from the field CITYST. This field represents a fixed-length character field, so the TRIM function is used to remove trailing blanks prior to extracting the characters. Assuming this field contained a city name and state abbreviation, this statement would return the two-character state abbreviation from the field.
Remaining Functions
The two remaining new functions are not at all similar, but they don't fall into the other categories.
The DATABASE function simply returns the value of the CURRENT SERVER special register. This value will generally be the name of your iSeries database.
FROM SYSIBM.SYSDUMMY1
The statement above will return a value that identifies the database to which the current connection is made. This value can be the name of your iSeries or another remote database name if a CONNECT statement has been used to connect to that remote database.
The MULTIPLY_ALT function gives you an alternate method for dealing with the multiplication of large numbers within an SQL statement. This is because of the way SQL deals with decimal places when multiplying two numbers. Basically, an SQL statement adds up the scale of the two numbers being multiplied and uses that value as the scale for the result. So if a decimal with a length of 25 with 10 decimals is multiplied by a decimal with a length of 10 with 5 decimals, the result will be a decimal with a length of 31 with 15 decimals. This will cause an overflow in the result field because the value can't be stored in that field.
This MULTIPLY_ALT function uses a more complex method of calculating the scale for the result value. As a result, this function is less likely to return an overflow value. Below is a sample statement that uses both a standard multiplication operator (*) and the MULTIPLY_ALT function.
MULTIPLY_ALT(12345678901234567898989898.99 , 1.00000005)
FROM SYSIBM/SYSDUMMY1
Note that while we are multiplying the same two values in each column, the first column returns an overflow value (+++++++++++++++++++++++++++++++++++++++) while the second column returns the result 12,345,679,518,518,512,960,718,293.9394. Notice that the resulting value is rounded to four decimal places.
Continuing the Expansion
The set of 25 functions added to SQL in V5R3 shows IBM's commitment to the continued expansion of this language. If, however, you don't see the function you need today, go ahead and write one. User-defined functions are a great way of expanding the SQL language on your own. For more details on this, check out my book SQL Built-In Functions and Stored Procedures from MC Press.
Mike Faust is an application programmer for Fidelity Integrated Financial Solutions in Maitland, Florida. Mike is also the author of the books The iSeries and AS/400 Programmer's Guide to Cool Things and Active Server Pages Primer and SQL Built-In Functions and Stored Procedures. You can contact Mike at
LATEST COMMENTS
MC Press Online