The TRIM function takes a character expression and returns that expression with leading and/or trailing pad characters removed.
Optional parameters indicate whether leading, or trailing, or both leading and trailing pad characters should be removed, and specify the pad character that is to be removed.
{ trimType [ trimCharacter ] FROM | trimCharacter FROM }
The trimCharacter is a characterExpression.
If trimSource's data type is CHAR or VARCHAR, the return type of the TRIM function will be VARCHAR. Otherwise the return type of the TRIM function will be CLOB.
-- returns 'derby' (no spaces)
VALUES TRIM(' derby ')
-- returns 'derby' (no spaces)
VALUES TRIM(BOTH ' ' FROM ' derby ')
-- returns 'derby ' (with a space at the end)
VALUES TRIM(LEADING ' ' FROM ' derby ')
-- returns ' derby' (with two spaces at the beginning)
VALUES TRIM(TRAILING ' ' FROM ' derby ')
-- returns NULL
VALUES TRIM(cast (null as char(1)) FROM ' derby ')
-- returns NULL
VALUES TRIM(' ' FROM cast(null as varchar(30)))
-- returns ' derb' (with a space at the beginning)
VALUES TRIM('y' FROM ' derby')
-- results in an error because trimCharacter can only be 1 character
VALUES TRIM('by' FROM ' derby')