Table 8.2. Supported escaped string functions
function | reported as supported | translation | comments |
---|---|---|---|
ascii(arg1) | yes | ascii(arg1) | |
char(arg1) | yes | chr(arg1) | |
concat(arg1,arg2...) | yes | (arg1||arg2...) | The JDBC specification only require the two arguments version, but supporting more arguments was so easy... |
insert(arg1,arg2,arg3,arg4) | no | overlay(arg1 placing arg4 from arg2 for arg3) | This function is not reported as supported since it changes the order of the arguments which can be a problem (for prepared statements by example). |
lcase(arg1) | yes | lower(arg1) | |
left(arg1,arg2) | yes | substring(arg1 for arg2) | |
length(arg1) | yes | length(trim(trailing from arg1)) | |
locate(arg1,arg2) | no | position(arg1 in arg2) | |
locate(arg1,arg2,arg3) | no | (arg2*sign(position(arg1 in substring(arg2 from arg3)+position(arg1 in substring(arg2 from arg3)) | Not reported as supported since the three arguments version duplicate and change the order of the arguments. |
ltrim(arg1) | yes | trim(leading from arg1) | |
repeat(arg1,arg2) | yes | repeat(arg1,arg2) | |
replace(arg1,arg2,arg3) | yes | replace(arg1,arg2,arg3) | Only reported as supported by 7.3 and above servers. |
right(arg1,arg2) | no | substring(arg1 from (length(arg1)+1-arg2)) | Not reported as supported since arg2 is duplicated. |
rtrim(arg1) | yes | trim(trailing from arg1) | |
space(arg1) | yes | repeat(' ',arg1) | |
substring(arg1,arg2) | yes | substr(arg1,arg2) | |
substring(arg1,arg2,arg3) | yes | substr(arg1,arg2,arg3) | |
ucase(arg1) | yes | upper(arg1) | |
soundex(arg1) | no | soundex(arg1) | Not reported as supported since it requires the fuzzystrmatch contrib module. |
difference(arg1,arg2) | no | difference(arg1,arg2) | Not reported as supported since it requires the fuzzystrmatch contrib module. |
Table 8.3. Supported escaped date/time functions
function | reported as supported | translation | comments |
---|---|---|---|
curdate() | yes | current_date | |
curtime() | yes | current_time | |
dayname(arg1) | yes | to_char(arg1,'Day') | |
dayofmonth(arg1) | yes | extract(day from arg1) | |
dayofweek(arg1) | yes | extract(dow from arg1)+1 | We must add 1 to be in the expected 1-7 range. |
dayofyear(arg1) | yes | extract(doy from arg1) | |
hour(arg1) | yes | extract(hour from arg1) | |
minute(arg1) | yes | extract(minute from arg1) | |
month(arg1) | yes | extract(month from arg1) | |
monthname(arg1) | yes | to_char(arg1,'Month') | |
now() | yes | now() | |
quarter(arg1) | yes | extract(quarter from arg1) | |
second(arg1) | yes | extract(second from arg1) | |
week(arg1) | yes | extract(week from arg1) | |
year(arg1) | yes | extract(year from arg1) | |
timestampadd(argIntervalType,argCount,argTimeStamp) | yes | ('(interval according to argIntervalType and argCount)'+argTimeStamp) | an argIntervalType value of SQL_TSI_FRAC_SECOND is not implemented since backend does not support it |
timestampdiff(argIntervalType,argTimeStamp1,argTimeStamp2) | not | extract((interval according to argIntervalType) from argTimeStamp2-argTimeStamp1 ) | only an argIntervalType value of SQL_TSI_FRAC_SECOND ,SQL_TSI_FRAC_MINUTE ,SQL_TSI_FRAC_HOUR or SQL_TSI_FRAC_DAY is supported |
Table 8.4. Supported escaped misc functions
function | reported as supported | translation | comments |
---|---|---|---|
database() | yes | current_database() | Only reported as supported by 7.3 and above servers. |
ifnull(arg1,arg2) | yes | coalesce(arg1,arg2) | |
user() | yes | user |