Previous Page TOC Index



APPENDIX F SCALAR FUNCTIONS


ODBC specifies five types of scalar functions:

The following sections list functions by function type. Descriptions include associated syntax.

String Functions

The following table lists string manipulation functions.

Character string literals used as arguments to scalar functions must be bounded by single quotes.

Arguments denoted as string_exp can be the name of a column, a string literal, or the result of another scalar function, where the underlying data type can be represented as SQL_CHAR, SQL_VARCHAR, or SQL_LONGVARCHAR.

Arguments denoted as start, length or count can be a numeric literal or the result of another scalar function, where the underlying data type can be represented as SQL_TINYINT, SQL_SMALLINT, or SQL_INTEGER.

The string functions listed here are 1-based, that is, the first character in the string is character 1.

Function

Description

ASCII(string_exp)

Returns the ASCII code value of the leftmost character of string_exp as an integer.

CHAR(code)

Returns the character that has the ASCII code value specified by code. The value of code should be between 0 and 255; otherwise, the return value is data source–dependent.

CONCAT(string_exp1, string_exp2)

Returns a character string that is the result of concatenating string_exp2 to string_exp1. If the column represented by string_exp1 or string_exp2 contained a NULL value, SOLID Server returns NULL.

INSERT(string_exp1, start, length, string_exp2)

Returns a character string where length characters have been deleted from string_exp1 beginning at start and where string_exp2 has been inserted into string_exp, beginning at start.

LCASE(string_exp)

Converts all upper case characters in string_exp to lower case.

LEFT(string_exp, count)

Returns the leftmost count of characters of string_exp.

LENGTH(string_exp)

Returns the number of characters in string_exp, excluding trailing blanks and the string termination character.

LOCATE(string_exp1, string_exp2[, start])

Returns the starting position of the first occurrence of string_exp1 within string_exp2. The search for the first occurrence of string_exp1 begins with the first character position in string_exp2 unless the optional argument, start, is specified. If start is specified, the search begins with the character position indicated by the value of start. The first character position in string_exp2 is indicated by the value 1. If string_exp1 is not found within string_exp2, the value 0 is returned.

LTRIM(string_exp)

Returns the characters of string_exp, with leading blanks removed.

REPEAT(string_exp,count)

Returns a character string composed of string_exp repeated count times.

REPLACE(string_exp1, string_exp2, string_exp3)

Replaces all occurrences of string_exp2 in string_exp1 with string_exp3.

RIGHT(string_exp, count)

Returns the rightmost count of characters of string_exp.

RTRIM(string_exp)

Returns the characters of string_exp with trailing blanks removed.

SPACE(count)

Returns a character string consisting of count spaces.

SUBSTRING(string_exp, start, length)

Returns a character string that is derived from string_exp beginning at the character position specified by start for length characters.

UCASE(string_exp)

Converts all lower case characters in string_exp to upper case.

Numeric Functions

The following table describes numeric functions that are included in the ODBC scalar function set.

Arguments denoted as numeric_exp can be the name of a column, the result of another scalar function, or a numeric literal, where the underlying data type could be represented as SQL_NUMERIC, SQL_DECIMAL, SQL_TINYINT, SQL_SMALLINT, SQL_INTEGER, SQL_BIGINT, SQL_FLOAT, SQL_REAL, or SQL_DOUBLE.

Arguments denoted as float_exp can be the name of a column, the result of another scalar function, or a numeric literal, where the underlying data type can be represented as SQL_FLOAT.

Arguments denoted as integer_exp can be the name of a column, the result of another scalar function, or a numeric literal, where the underlying data type can be represented as SQL_TINYINT, SQL_SMALLINT, SQL_INTEGER, or SQL_BIGINT.

Function

Description

ABS(numeric_exp)

Returns the absolute value of numeric_exp.

ACOS(float_exp)

Returns the arccosine of float_exp as an angle, expressed in radians.

ASIN(float_exp)

Returns the arcsine of float_exp as an angle, expressed in radians.

ATAN(float_exp)

Returns the arctangent of float_exp as an angle, expressed in radians.

ATAN2(float_exp1, float_exp2)

Returns the arctangent of the x and y coordinates, specified by float_exp1 and float_exp2, respectively, as an angle, expressed in radians.

CEILING(numeric_exp)

Returns the smallest integer greater than or equal to numeric_exp.

COS(float_exp)

Returns the cosine of float_exp, where float_exp is an angle expressed in radians.

COT(float_exp)

Returns the cotangent of float_exp, where float_exp is an angle expressed in radians.

DEGREES(numeric_exp)

Returns the number of degrees converted from numeric_exp radians.

EXP(float_exp)

Returns the exponential value of float_exp.

FLOOR(numeric_exp)

Returns largest integer less than or equal to numeric_exp.

LOG(float_exp)

Returns the natural logarithm of float_exp.

LOG10(float_exp)

Returns the base 10 logarithm of float_exp.

MOD(integer_exp1, integer_exp2)

Returns the remainder (modulus) of integer_exp1 divided by integer_exp2.

PI( )

Returns the constant value of pi as a floating point value.

POWER(numeric_exp, integer_exp)

Returns the value of numeric_exp to the power of integer_exp.

RADIANS(numeric_exp)

Returns the number of radians converted from numeric_exp degrees.

ROUND(numeric_exp, integer_exp)

Returns numeric_exp rounded to integer_exp places right of the decimal point. If integer_exp is negative, numeric_exp is rounded to |integer_exp| places to the left of the decimal point.

SIGN(numeric_exp)

Returns an indicator or the sign of numeric_exp. If numeric_exp is less than zero, –1 is returned. If numeric_exp equals zero, 0 is returned. If numeric_exp is greater than zero, 1 is returned.

SIN(float_exp)

Returns the sine of float_exp, where float_exp is an angle expressed in radians.

SQRT(float_exp)

Returns the square root of float_exp.

TAN(float_exp)

Returns the tangent of float_exp, where float_exp is an angle expressed in radians.

TRUNCATE(numeric_exp, integer_exp)

Returns numeric_exp truncated to integer_exp places right of the decimal point. If integer_exp is negative, numeric_exp is truncated to |integer_exp| places to the left of the decimal point.

Time and Date Functions

The following table lists time and date functions that are included in the ODBC scalar function set.

Arguments denoted as timestamp_exp can be the name of a column, the result of another scalar function, or a time, date, or timestamp literal, where the underlying data type could be represented as SQL_CHAR, SQL_VARCHAR, SQL_TIME, SQL_DATE, or SQL_TIMESTAMP.

Arguments denoted as date_exp can be the name of a column, the result of another scalar function, or a date or timestamp literal, where the underlying data type could be represented as SQL_CHAR, SQL_VARCHAR, SQL_DATE, or SQL_TIMESTAMP.

Arguments denoted as time_exp can be the name of a column, the result of another scalar function, or a time or timestamp literal, where the underlying data type could be represented as SQL_CHAR, SQL_VARCHAR, SQL_TIME, or SQL_TIMESTAMP.

Values returned are represented as ODBC data types.

Function

Description

CURDATE( )

Returns the current date as a date value.

CURTIME( )

Returns the current local time as a time value.

DAYNAME(date_exp)

Returns a character string containing the data source–specific name of the day (for example, Sunday, through Saturday or Sun. through Sat. for a data source that uses English, or Sonntag through Samstag for a data source that uses German) for the day portion of date_exp.

DAYOFMONTH(date_exp)

Returns the day of the month in date_exp as an integer value in the range of 1–31.

DAYOFWEEK(date_exp)

Returns the day to the week in date_exp as an integer value in the range of 1–7, where 1 represents Sunday.

DAYOFYEAR(date_exp)

Returns the day of the year in date_exp as an integer value in the range of 1–366.

HOUR(time_exp)

Returns the hour in time_exp as an integer value in the range of 0 –23.

MINUTE(time_exp)

Returns the minute in time_exp as an integer value in the range of 0 –59.

MONTH(date_exp)

Returns the month in date_exp as an integer value in the range of 1–12.

MONTHNAME(date_exp)

Returns a character string containing the data source–specific name of the month (for example, January throughDecember or Jan. through Dec. for a data source that uses English, or Januar through Dezember for a data source that uses German) for the month portion of date_exp.

NOW( )

Returns current date and time as a timestamp value.

QUARTER(date_exp)

Returns the quarter in date_exp as an integer value in the range of 1– 4, where 1 represents January 1 through March 31.

SECOND(time_exp)

Returns the second in time_exp as an integer value in the range of 0 –59.

TIMESTAMPADD(interval, integer_exp, timestamp_exp)

Returns the timestamp calculated by adding integer_exp intervals of type interval to timestamp_exp. Valid values of interval are the following keywords:

SQL_TSI_FRAC_SECOND
SQL_TSI_SECOND
SQL_TSI_MINUTE
SQL_TSI_HOUR
SQL_TSI_DAY
SQL_TSI_WEEK
SQL_TSI_MONTH
SQL_TSI_QUARTER
SQL_TSI_YEAR

where fractional seconds are expressed in billionths of a second. For example, the following SQL statement returns the name of each employee and their one-year anniversary dates:

SELECT NAME,
{fn TIMESTAMPADD(SQL_TSI_YEAR,
1, HIRE_DATE)} FROM EMPLOYEES

If timestamp_exp is a time value and interval specifies days, weeks, months, quarters, or years, the date portion of timestamp_exp is set to the current date before calculating the resulting timestamp.

If timestamp_exp is a date value and interval specifies fractional seconds, seconds, minutes, or hours, the time portion of timestamp_exp is set to 0 before calculating the resulting timestamp.

An application determines which intervals a data source supports by calling SQLGetInfo with the SQL_TIMEDATE_ADD_INTERVALS option.

TIMESTAMPDIFF(interval, timestamp_exp1, timestamp_exp2)

Returns the integer number of intervals of type interval by which timestamp_exp2 is greater than timestamp_exp1. Valid values of interval are the following keywords:

SQL_TSI_FRAC_SECOND
SQL_TSI_SECOND
SQL_TSI_MINUTE
SQL_TSI_HOUR
SQL_TSI_DAY
SQL_TSI_WEEK
SQL_TSI_MONTH
SQL_TSI_QUARTER
SQL_TSI_YEAR

where fractional seconds are expressed in billionths of a second. For example, the following SQL statement returns the name of each employee and the number of years they have been employed.

SELECT NAME,
{fn TIMESTAMPDIFF(SQL_TSI_YEAR,
{fn CURDATE()}, HIRE_DATE)}
FROM EMPLOYEES

If either timestamp expression is a time value and interval specifies days, weeks, months, quarters, or years, the date portion of that timestamp is set to the current date before calculating the difference between the timestamps.

If either timestamp expression is a date value and interval specifies fractional seconds, seconds, minutes, or hours, the time portion of of that timestamp is set to 0 before calculating the difference between the timestamps.

An application determines which intervals a data source supports by calling SQLGetInfo with the SQL_TIMEDATE_DIFF_INTERVALS option.

WEEK(date_exp)

Returns the week of the year in date_exp as an integer value in the range of 1–53.

YEAR(date_exp)

Returns the year in date_exp as an integer value. The range is data source–dependent.

System Functions

The following table lists system functions that are included in the ODBC scalar function set.

Arguments denoted as exp can be the name of a column, the result of another scalar function, or a literal, where the underlying data type could be represented as SQL_NUMERIC, SQL_DECIMAL, SQL_TINYINT, SQL_SMALLINT, SQL_INTEGER, SQL_BIGINT, SQL_FLOAT, SQL_REAL, SQL_DOUBLE, SQL_DATE, SQL_TIME, or SQL_TIMESTAMP.

Arguments denoted as value can be a literal constant, where the underlying data type can be represented as SQL_NUMERIC, SQL_DECIMAL, SQL_TINYINT, SQL_SMALLINT, SQL_INTEGER, SQL_BIGINT, SQL_FLOAT, SQL_REAL, SQL_DOUBLE, SQL_DATE, SQL_TIME, or SQL_TIMESTAMP.

Values returned are represented as ODBC data types.

Function

Description

IFNULL(exp,value)

If exp is null, value is returned. If exp is not null, exp is returned. The possible data type(s) of value must be compatible with the data type of exp.

USER( )

Returns the user’s authorization name. ( The user’s authorization name is also available via SQLGetInfo by specifying the information type: SQL_USER_NAME or by using pseudocolumn ‘USER’ SQL: SELECT USER...)

Explicit Data Type Conversion

Explicit data type conversion is specified in terms of ODBC SQL data type definitions.

The ODBC syntax for the explicit data type conversion function does not restrict conversions. The validity of specific conversions of one data type to another data type will be determined by each driver-specific implementation. The driver will, as it translates the ODBC syntax into the native syntax, reject those conversions that, although legal in the ODBC syntax, are not supported by the data source. The ODBC function SQLGetInfo provides a way to inquire about conversions supported by the data source.

The format of the CONVERT function is:

CONVERT(value_exp, data_type)

The function returns the value specified by value_exp converted to the specified data_type, where data_type is one of the following keywords:

SQL_BIGINT

SQL_BINARY

SQL_BIT

SQL_CHAR

SQL_DATE

SQL_DECIMAL

SQL_DOUBLE

SQL_FLOAT

SQL_INTEGER

SQL_LONGVARBINARY

SQL_LONGVARCHAR

SQL_NUMERIC

SQL_REAL

SQL_SMALLINT

SQL_TIME

SQL_TIMESTAMP

SQL_TINYINT

SQL_VARBINARY

SQL_VARCHAR


The ODBC syntax for the explicit data type conversion function does not support specification of conversion format. If specification of explicit formats is supported by the underlying data source, a driver must specify a default value or implement format specification.

The argument value_exp can be a column name, the result of another scalar function, or a numeric or string literal. For example:

{ fn CONVERT( { fn CURDATE() }, SQL_CHAR) }

converts the output of the CURDATE scalar function to a character string..

The following two examples illustrate the use of the CONVERT function. These examples assume the existence of a table called EMPLOYEES, with an EMPNO column of type SQL_SMALLINT and an EMPNAME column of type SQL_CHAR.

If an application specifies the following:

SELECT EMPNO FROM EMPLOYEES WHERE
--(*vendor(Microsoft),product(ODBC) fn CONVERT(EMPNO,SQL_CHAR)*)-- LIKE '1%'

or its equivalent in shorthand form:

SELECT EMPNO FROM EMPLOYEES WHERE {fn CONVERT(EMPNO,SQL_CHAR)} LIKE '1%'

SOLID ODBC driver translates the request to:

SELECT EMPNO FROM EMPLOYEES WHERE CONVERT_CHAR(EMPNO) LIKE '1%'

If an application specifies the following:

SELECT --(*vendor(Microsoft),product(ODBC) fn ABS(EMPNO)*)--, --(*vendor(Microsoft),product(ODBC) fn CONVERT(EMPNAME,SQL_SMALLINT)*)-- FROM EMPLOYEES WHERE EMPNO <> 0

or its equivalent in shorthand form:

SELECT {fn ABS(EMPNO)}, {fn CONVERT(EMPNAME,SQL_SMALLINT)} FROM EMPLOYEES WHERE EMPNO <> 0

SOLID ODBC driver translates the request to:

SELECT ABS(EMPNO), CONVERT_SMALLINT(EMPNAME) FROM EMPLOYEES WHERE EMPNO <> 0

Previous Page TOC Index

Copyright © 1992-1997 Solid Information Technology Ltd All rights reserved.