SUBSTRING
Extracts a range of characters from a string.
Syntax
SUBSTRING(str, start, len) SUBSTR(str, start, len) SUBSTRING(str, start) SUBSTR(str, start) SUBSTRING(str FROM start FOR len) SUBSTR(str FROM start FOR len) SUBSTRING(str FROM start) SUBSTR(str FROM start)
Arguments
str: any string or binary object
start: the one-indexed position to start at. If negative, counts from the end.
len: the number of characters to extract. Forms without
len
, extract characters until the end of the string.
Return Type
String
Remarks
In
SUBSTR
orSUBSTRING
, the starting index point of a string is1
(0
is an alias for1
).
Examples
In the following example, the starting index 3
represents the third character in the string, because the index starts from 1
.
SELECT SUBSTRING('1234567890', 3, 3); +-------------------------------+ | SUBSTRING('1234567890', 3, 3) | +-------------------------------+ | 345 | +-------------------------------+
In the following example, the substring is returned from the end, because the starting index is a negative number.
SELECT SUBSTRING('1234567890', -3, 3); +--------------------------------+ | SUBSTRING('1234567890', -3, 3) | +--------------------------------+ | 890 | +--------------------------------+
Implicit Collation
When character_set_server
is set to utf8
, string literals with characters using 4-byte encoding are implicitly assigned binary collation and processed as a sequence of bytes rather than characters. This implicit conversion to binary collation causes string functions to return unexpected results. To avoid using implicit binary collation, either use explicit type casting or use database columns defined with the utf8mb4
character set.
For more information, refer to Implicit Collation in Special Cases.