1 Database functions

Even most of SQL functions have a common name across different database agents, when writing database independent code you may need some way to get the appropriate name of an SQL function in current agent. For example, SUBSTR function witch is supported by most database agents is called SUBSTRING in SQLServer.

The following table shows the function names that can be used to write database independent code using the fn method.

Function Informix Oracle DB2 Postgres MYSQL SQLServer
SUBSTR SUBSTR SUBSTR SUBSTR SUBSTR SUBSTR SUBSTRING
LENGTH LENGTH LENGTH LENGTH LENGTH LENGTH LEN
UPPER UPPER UPPER UPPER UPPER UPPER UPPER
LOWER LOWER LOWER LOWER LOWER LOWER LOWER
TRIM TRIM TRIM TRIM TRIM TRIM TRIM
RTRIM RTRIM RTRIM RTRIM RTRIM RTRIM RTRIM
LTRIM LTRIM LTRIM LTRIM LTRIM LTRIM LTRIM
LPAD LPAD LPAD LPAD LPAD LPAD LPAD
RPAD RPAD RPAD RPAD RPAD RPAD RPAD
NVL NVL NVL COALESCE COALESCE IFNULL ISNULL

2 SUBSTR(source_string,start_position,length)

The SUBSTR function returns a subset of source_string. The subset begins at the column position that start_position specifies. The following table shows how the database server determines the starting position of the returned subset based on the input value of the start_position.

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT SUBSTR(tabname, 1, 20), ${Ax.db.fn("SUBSTR")}(tabname, 1, 20)
          FROM systables
         WHERE tabid = 1
`);

</script>

The length parameter specifies the number of logical characters (not the number of bytes) in the subset. If you omit the length parameter, the SUBSTR function returns the entire portion of source_string that begins at start_position.

3 LENGTH(source_string)

The LENGTH functions return the length of char.

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT LENGTH(colname), ${Ax.db.fn("LENGTH")}(colname)
          FROM systables
         WHERE tabid = 1
`);

</script>

Informix

In Informix the LENGTH function exclude any trailing blank spaces.
Copy
select length('    a   ') from systables where tabid = 1;
5

4 UPPER(source_string)

UPPER returns char, with all letters uppercase.

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT UPPER(colname), ${Ax.db.fn("UPPER")}(colname)
          FROM systables
         WHERE tabid = 1
`);

</script>

5 LOWER(source_string)

LOWER returns char, with all letters lowercase.

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT LOWER(colname), ${Ax.db.fn("LOWER")}(colname)
          FROM systables
         WHERE tabid = 1
`);

</script>

6 TRIM(source_string)

TRIM enables you to trim leading and trailing characters from a character string.

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT TRIM(colname), ${Ax.db.fn("TRIM")}(colname)
          FROM systables
         WHERE tabid = 1
`);

</script>

7 RTRIM(source_string [,pad_string])

The RTRIM function removes specified trailing pad characters from a string.

The first argument to the RTRIM function must be a character expression from which to delete trailing pad characters. The optional second argument is a character expression that evaluates to a string of pad characters. If no second argument is provided, only blank characters are regarded as pad characters.

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT RTRIM(colname), ${Ax.db.fn("RTRIM")}(colname)
          FROM systables
         WHERE tabid = 1
`);

</script>

In the following example, the pad_string is ' theend':

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT RTRIM('This is the text...   theend', ' theend') , ${Ax.db.fn("RTRIM")}('This is the text...   theend', ' theend')
          FROM systables
         WHERE tabid = 1
`);

</script>
This is the text...

8 LTRIM(source_string [,pad_string])

The LTRIM function removes specified leading pad characters from a string.

The first argument to the LTRIM function must be a character expression from which to delete leading pad characters. The optional second argument is a character expression that evaluates to a string of pad characters. If no second argument is provided, only blank characters are regarded as pad characters.

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT LTRIM(colname), ${Ax.db.fn("LTRIM")}(colname)
          FROM systables
         WHERE tabid = 1
`);

</script>

IIn the following example, the pad_string is 'Hello':

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT LTRIM('Hellohello world!', 'Hello') , ${Ax.db.fn("LTRIM")}('Hellohello world!', 'Hello')
          FROM systables
         WHERE tabid = 1
`);

</script>
hello world!

9 LPAD(source_string, lenght [, pad_string])

The LPAD function returns an expression, left-padded to a specified length with the specified characters; or, when the expression to be padded is longer than the length specified after padding, only that portion of the expression that fits into the specified length.

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT LPAD('This is text', 16, '-_') , ${Ax.db.fn("LPAD")}('This is text', 16, '-_')
          FROM systables
         WHERE tabid = 1
`);

</script>
-_-_This is text

10 RPAD(source_string)

The RPAD function returns an expression, right-padded to a specified length with the specified characters; or, when the expression to be padded is longer than the length specified after padding, only that portion of the expression that fits into the specified length.

Copy
<script>
    return Ax.db.executeQuery(`
        SELECT RPAD('This is text', 16, '-_') , ${Ax.db.fn("RPAD")}('This is text', 16, '-_')
          FROM systables
         WHERE tabid = 1
`);

</script>
This is text-_-_

11 NVL(expr1, expr2)

NVL lets you replace null (returned as a blank) with a string in the results of a query. If expr1 is null, then NVL returns expr2. If expr1 is not null, then NVL returns expr1.

NVL is specifically integrated as a database method. The reason is that when processing string variables you need to quote them. So, when using string variables you should use the NVL built-in processor from database object.

Copy
<script>
    var char1 = null;
    console.log(`SELECT ${Ax.db.NVL(char1, 'test')} FROM systables WHERE tabid = 1`);
    console.log(Ax.db.executeQuery(`
        SELECT ${Ax.db.NVL(char1, 'test')} FROM systables WHERE tabid = 1
`));
    var char1 = 'world';
    console.log(`SELECT ${Ax.db.NVL(char1, 'test')} FROM systables WHERE tabid = 1`);
    console.log(Ax.db.executeQuery(`
        SELECT ${Ax.db.NVL(char1, 'test')} FROM systables WHERE tabid = 1
`));
</script>
SELECT nvl(NULL, 'test') FROM systables WHERE tabid = 1
+----------------------------------------+
|(constant)                              |
+----------------------------------------+
|test                                    |
+----------------------------------------+

SELECT nvl('world', 'test') FROM systables WHERE tabid = 1
+----------+
|(constant)|
+----------+
|world     |
+----------+