Click here to view and discuss this page in DocCommentXchange. In the future, you will be sent there automatically.

SQL Anywhere 10.0.1 » SQL Anywhere Server - SQL Reference » SQL Functions » Alphabetical list of functions

STUFF function [String] Next Page

SUBSTRING function [String]


Returns a substring of a string.

Syntax

{ SUBSTRING | SUBSTR } ( string-expression, start
[, length ] )

Parameters

string-expression    The string from which a substring is to be returned.

start    The start position of the substring to return, in characters.

length    The length of the substring to return, in characters. If length is specified, the substring is restricted to that length.

Remarks

The behavior of this function depends on the setting of the ansi_substring database option. When the ansi_substring option is set to On (the default), the behavior of the SUBSTRING function corresponds to ANSI/ISO SQL/2003 behavior. The behavior is as follows:

ansi_substring option setting start value length value
On The first character in the string is at position 1. A negative or zero start offset is treated as if the string were padded on the left with non-characters.

A positive length specifies that the substring ends length characters to the right of the starting position.

A negative length returns an error.

Off

The first character in the string is at position 1. A negative starting position specifies a number of characters from the end of the string instead of the beginning.

If start is zero and length is non-negative, a start value of 1 is used. If start is zero and length is negative, a start value of -1 is used.

A positive length specifies that the substring ends length characters to the right of the starting position.

A negative length returns at most length characters up to, and including, the starting position, from the left of the starting position.

If string-expression is of binary data type, the SUBSTRING function behaves as BYTE_SUBSTR.

It is recommended that you avoid using non-positive start offsets or negative lengths with the SUBSTRING function. Where possible, use the LEFT or RIGHT functions instead.

This function supports NCHAR inputs and/or outputs. Whenever possible, if the input string uses character length semantics the return value is described in terms of character length semantics.

See also
Standards and compatibility
Example

The following table shows the values returned by the SUBSTRING function when used in a SELECT statement, with the ansi_substring option set to On and Off.

ExampleResult with ansi_substring set to OnResult with ansi_substring set to Off
SUBSTRING( 'front yard', 1, 4 )fronfron
SUBSTRING( 'back yard', 6, 4 )yardyard
SUBSTR( 'abcdefgh', 0, -2 )Returns an errorgh
SUBSTR( 'abcdefgh', -2, 2 )Returns an empty stringgh
SUBSTR( 'abcdefgh', 2, -2 )Returns an errorab
SUBSTR( 'abcdefgh', 2, -4 )Returns an errorab
SUBSTR( 'abcdefgh', 2, -1 )Returns an errorb