String-valued functions return NULL
if the
length of the result would be greater than the value of the
max_allowed_packet
system variable. See
Section 7.5.2, “Tuning Server Parameters”.
For functions that operate on string positions, the first position is numbered 1.
-
Returns the numeric value of the leftmost character of the string
str
. Returns0
ifstr
is the empty string. ReturnsNULL
ifstr
isNULL
.ASCII()
works for characters with numeric values from0
to255
.mysql>
SELECT ASCII('2');
-> 50 mysql>SELECT ASCII(2);
-> 50 mysql>SELECT ASCII('dx');
-> 100See also the
ORD()
function. -
Returns a string representation of the binary value of
N
, whereN
is a longlong (BIGINT
) number. This is equivalent toCONV(
N
,10,2). ReturnsNULL
ifN
isNULL
.mysql>
SELECT BIN(12);
-> '1100' -
Returns the length of the string
str
in bits.mysql>
SELECT BIT_LENGTH('text');
-> 32 -
CHAR(
N
,... [USINGcharset_name
])CHAR()
interprets each argumentN
as an integer and returns a string consisting of the characters given by the code values of those integers.NULL
values are skipped.mysql>
SELECT CHAR(77,121,83,81,'76');
-> 'MySQL' mysql>SELECT CHAR(77,77.3,'77.3');
-> 'MMM'As of MySQL 5.0.15,
CHAR()
arguments larger than 255 are converted into multiple result bytes. For example,CHAR(256)
is equivalent toCHAR(1,0)
, andCHAR(256*256)
is equivalent toCHAR(1,0,0)
:mysql>
SELECT HEX(CHAR(1,0)), HEX(CHAR(256));
+----------------+----------------+ | HEX(CHAR(1,0)) | HEX(CHAR(256)) | +----------------+----------------+ | 0100 | 0100 | +----------------+----------------+ mysql>SELECT HEX(CHAR(1,0,0)), HEX(CHAR(256*256));
+------------------+--------------------+ | HEX(CHAR(1,0,0)) | HEX(CHAR(256*256)) | +------------------+--------------------+ | 010000 | 010000 | +------------------+--------------------+By default,
CHAR()
returns a binary string. To produce a string in a given character set, use the optionalUSING
clause:mysql>
SELECT CHARSET(CHAR(0x65)), CHARSET(CHAR(0x65 USING utf8));
+---------------------+--------------------------------+ | CHARSET(CHAR(0x65)) | CHARSET(CHAR(0x65 USING utf8)) | +---------------------+--------------------------------+ | binary | utf8 | +---------------------+--------------------------------+If
USING
is given and the result string is illegal for the given character set, a warning is issued. Also, if strict SQL mode is enabled, the result fromCHAR()
becomesNULL
.Before MySQL 5.0.15,
CHAR()
returns a string in the connection character set and theUSING
clause is unavailable. In addition, each argument is interpreted modulo 256, soCHAR(256)
andCHAR(256*256)
both are equivalent toCHAR(0)
. -
Returns the length of the string
str
, measured in characters. A multi-byte character counts as a single character. This means that for a string containing five two-byte characters,LENGTH()
returns10
, whereasCHAR_LENGTH()
returns5
. -
CHARACTER_LENGTH()
is a synonym forCHAR_LENGTH()
. -
Returns the string that results from concatenating the arguments. May have one or more arguments. If all arguments are non-binary strings, the result is a non-binary string. If the arguments include any binary strings, the result is a binary string. A numeric argument is converted to its equivalent binary string form; if you want to avoid that, you can use an explicit type cast, as in this example:
SELECT CONCAT(CAST(
int_col
AS CHAR),char_col
);CONCAT()
returnsNULL
if any argument isNULL
.mysql>
SELECT CONCAT('My', 'S', 'QL');
-> 'MySQL' mysql>SELECT CONCAT('My', NULL, 'QL');
-> NULL mysql>SELECT CONCAT(14.3);
-> '14.3' -
CONCAT_WS(
separator
,str1
,str2
,...)CONCAT_WS()
stands for Concatenate With Separator and is a special form ofCONCAT()
. The first argument is the separator for the rest of the arguments. The separator is added between the strings to be concatenated. The separator can be a string, as can the rest of the arguments. If the separator isNULL
, the result isNULL
.mysql>
SELECT CONCAT_WS(',','First name','Second name','Last Name');
-> 'First name,Second name,Last Name' mysql>SELECT CONCAT_WS(',','First name',NULL,'Last Name');
-> 'First name,Last Name'CONCAT_WS()
does not skip empty strings. However, it does skip anyNULL
values after the separator argument. -
Converts numbers between different number bases. Returns a string representation of the number
N
, converted from basefrom_base
to baseto_base
. ReturnsNULL
if any argument isNULL
. The argumentN
is interpreted as an integer, but may be specified as an integer or a string. The minimum base is2
and the maximum base is36
. Ifto_base
is a negative number,N
is regarded as a signed number. Otherwise,N
is treated as unsigned.CONV()
works with 64-bit precision.mysql>
SELECT CONV('a',16,2);
-> '1010' mysql>SELECT CONV('6E',18,8);
-> '172' mysql>SELECT CONV(-17,10,-18);
-> '-H' mysql>SELECT CONV(10+'10'+'10'+0xa,10,10);
-> '40' -
Returns
str1
ifN
=1
,str2
ifN
=2
, and so on. ReturnsNULL
ifN
is less than1
or greater than the number of arguments.ELT()
is the complement ofFIELD()
.mysql>
SELECT ELT(1, 'ej', 'Heja', 'hej', 'foo');
-> 'ej' mysql>SELECT ELT(4, 'ej', 'Heja', 'hej', 'foo');
-> 'foo' -
EXPORT_SET(
bits
,on
,off
[,separator
[,number_of_bits
]])Returns a string such that for every bit set in the value
bits
, you get anon
string and for every reset bit, you get anoff
string. Bits inbits
are examined from right to left (from low-order to high-order bits). Strings are added to the result from left to right, separated by theseparator
string (the default being the comma character ‘,
’). The number of bits examined is given bynumber_of_bits
(defaults to 64).mysql>
SELECT EXPORT_SET(5,'Y','N',',',4);
-> 'Y,N,Y,N' mysql>SELECT EXPORT_SET(6,'1','0',',',10);
-> '0,1,1,0,0,0,0,0,0,0' -
Returns the index (position) of
str
in thestr1
,str2
,str3
,...
list. Returns0
ifstr
is not found.If all arguments to
FIELD()
are strings, all arguments are compared as strings. If all arguments are numbers, they are compared as numbers. Otherwise, the arguments are compared as double.If
str
isNULL
, the return value is0
becauseNULL
fails equality comparison with any value.FIELD()
is the complement ofELT()
.mysql>
SELECT FIELD('ej', 'Hej', 'ej', 'Heja', 'hej', 'foo');
-> 2 mysql>SELECT FIELD('fo', 'Hej', 'ej', 'Heja', 'hej', 'foo');
-> 0 -
Returns a value in the range of 1 to
N
if the stringstr
is in the string liststrlist
consisting ofN
substrings. A string list is a string composed of substrings separated by ‘,
’ characters. If the first argument is a constant string and the second is a column of typeSET
, theFIND_IN_SET()
function is optimized to use bit arithmetic. Returns0
ifstr
is not instrlist
or ifstrlist
is the empty string. ReturnsNULL
if either argument isNULL
. This function does not work properly if the first argument contains a comma (‘,
’) character.mysql>
SELECT FIND_IN_SET('b','a,b,c,d');
-> 2 -
Formats the number
X
to a format like'#,###,###.##'
, rounded toD
decimal places, and returns the result as a string. IfD
is0
, the result has no decimal point or fractional part.mysql>
SELECT FORMAT(12332.123456, 4);
-> '12,332.1235' mysql>SELECT FORMAT(12332.1,4);
-> '12,332.1000' mysql>SELECT FORMAT(12332.2,0);
-> '12,332' -
If
N_or_S
is a number, returns a string representation of the hexadecimal value ofN
, whereN
is a longlong (BIGINT
) number. This is equivalent toCONV(
N
,10,16).If
N_or_S
is a string, returns a hexadecimal string representation ofN_or_S
where each character inN_or_S
is converted to two hexadecimal digits.mysql>
SELECT HEX(255);
-> 'FF' mysql>SELECT 0x616263;
-> 'abc' mysql>SELECT HEX('abc');
-> 616263 -
Returns the string
str
, with the substring beginning at positionpos
andlen
characters long replaced by the stringnewstr
. Returns the original string ifpos
is not within the length of the string. Replaces the rest of the string from positionpos
islen
is not within the length of the rest of the string. ReturnsNULL
if any argument isNULL
.mysql>
SELECT INSERT('Quadratic', 3, 4, 'What');
-> 'QuWhattic' mysql>SELECT INSERT('Quadratic', -1, 4, 'What');
-> 'Quadratic' mysql>SELECT INSERT('Quadratic', 3, 100, 'What');
-> 'QuWhat'This function is multi-byte safe.
-
Returns the position of the first occurrence of substring
substr
in stringstr
. This is the same as the two-argument form ofLOCATE()
, except that the order of the arguments is reversed.mysql>
SELECT INSTR('foobarbar', 'bar');
-> 4 mysql>SELECT INSTR('xbar', 'foobar');
-> 0This function is multi-byte safe, and is case sensitive only if at least one argument is a binary string.
-
LCASE()
is a synonym forLOWER()
. -
Returns the leftmost
len
characters from the stringstr
, orNULL
if any argument isNULL
.mysql>
SELECT LEFT('foobarbar', 5);
-> 'fooba' -
Returns the length of the string
str
, measured in bytes. A multi-byte character counts as multiple bytes. This means that for a string containing five two-byte characters,LENGTH()
returns10
, whereasCHAR_LENGTH()
returns5
.mysql>
SELECT LENGTH('text');
-> 4 -
Reads the file and returns the file contents as a string. To use this function, the file must be located on the server host, you must specify the full pathname to the file, and you must have the
FILE
privilege. The file must be readable by all and its size less thanmax_allowed_packet
bytes.If the file does not exist or cannot be read because one of the preceding conditions is not satisfied, the function returns
NULL
.As of MySQL 5.0.19, the
character_set_filesystem
system variable controls interpretation of filenames that are given as literal strings.mysql>
UPDATE t
SET blob_col=LOAD_FILE('/tmp/picture')
WHERE id=1;
-
LOCATE(
substr
,str
),LOCATE(
substr
,str
,pos
)The first syntax returns the position of the first occurrence of substring
substr
in stringstr
. The second syntax returns the position of the first occurrence of substringsubstr
in stringstr
, starting at positionpos
. Returns0
ifsubstr
is not instr
.mysql>
SELECT LOCATE('bar', 'foobarbar');
-> 4 mysql>SELECT LOCATE('xbar', 'foobar');
-> 0 mysql>SELECT LOCATE('bar', 'foobarbar', 5);
-> 7This function is multi-byte safe, and is case-sensitive only if at least one argument is a binary string.
-
Returns the string
str
with all characters changed to lowercase according to the current character set mapping. The default islatin1
(cp1252 West European).mysql>
SELECT LOWER('QUADRATICALLY');
-> 'quadratically'This function is multi-byte safe.
-
Returns the string
str
, left-padded with the stringpadstr
to a length oflen
characters. Ifstr
is longer thanlen
, the return value is shortened tolen
characters.mysql>
SELECT LPAD('hi',4,'??');
-> '??hi' mysql>SELECT LPAD('hi',1,'??');
-> 'h' -
Returns the string
str
with leading space characters removed.mysql>
SELECT LTRIM(' barbar');
-> 'barbar'This function is multi-byte safe.
-
Returns a set value (a string containing substrings separated by ‘
,
’ characters) consisting of the strings that have the corresponding bit inbits
set.str1
corresponds to bit 0,str2
to bit 1, and so on.NULL
values instr1
,str2
,...
are not appended to the result.mysql>
SELECT MAKE_SET(1,'a','b','c');
-> 'a' mysql>SELECT MAKE_SET(1 | 4,'hello','nice','world');
-> 'hello,world' mysql>SELECT MAKE_SET(1 | 4,'hello','nice',NULL,'world');
-> 'hello' mysql>SELECT MAKE_SET(0,'a','b','c');
-> '' -
MID(
str
,pos
,len
) is a synonym forSUBSTRING(
str
,pos
,len
). -
Returns a string representation of the octal value of
N
, whereN
is a longlong (BIGINT
) number. This is equivalent toCONV(
N
,10,8). ReturnsNULL
ifN
isNULL
.mysql>
SELECT OCT(12);
-> '14' -
OCTET_LENGTH()
is a synonym forLENGTH()
. -
If the leftmost character of the string
str
is a multi-byte character, returns the code for that character, calculated from the numeric values of its constituent bytes using this formula:(1st byte code) + (2nd byte code × 256) + (3rd byte code × 2562) ...
If the leftmost character is not a multi-byte character,
ORD()
returns the same value as theASCII()
function.mysql>
SELECT ORD('2');
-> 50 -
POSITION(
substr
INstr
) is a synonym forLOCATE(
substr
,str
). -
Quotes a string to produce a result that can be used as a properly escaped data value in an SQL statement. The string is returned enclosed by single quotes and with each instance of single quote (‘
'
’), backslash (‘\
’), ASCIINUL
, and Control-Z preceded by a backslash. If the argument isNULL
, the return value is the word “NULL” without enclosing single quotes.mysql>
SELECT QUOTE('Don\'t!');
-> 'Don\'t!' mysql>SELECT QUOTE(NULL);
-> NULL -
Returns a string consisting of the string
str
repeatedcount
times. Ifcount
is less than 1, returns an empty string. ReturnsNULL
ifstr
orcount
areNULL
.mysql>
SELECT REPEAT('MySQL', 3);
-> 'MySQLMySQLMySQL' -
Returns the string
str
with all occurrences of the stringfrom_str
replaced by the stringto_str
.REPLACE()
performs a case-sensitive match when searching forfrom_str
.mysql>
SELECT REPLACE('www.mysql.com', 'w', 'Ww');
-> 'WwWwWw.mysql.com'This function is multi-byte safe.
-
Returns the string
str
with the order of the characters reversed.mysql>
SELECT REVERSE('abc');
-> 'cba'This function is multi-byte safe.
-
Returns the rightmost
len
characters from the stringstr
, orNULL
if any argument isNULL
.mysql>
SELECT RIGHT('foobarbar', 4);
-> 'rbar'This function is multi-byte safe.
-
Returns the string
str
, right-padded with the stringpadstr
to a length oflen
characters. Ifstr
is longer thanlen
, the return value is shortened tolen
characters.mysql>
SELECT RPAD('hi',5,'?');
-> 'hi???' mysql>SELECT RPAD('hi',1,'?');
-> 'h'This function is multi-byte safe.
-
Returns the string
str
with trailing space characters removed.mysql>
SELECT RTRIM('barbar ');
-> 'barbar'This function is multi-byte safe.
-
Returns a soundex string from
str
. Two strings that sound almost the same should have identical soundex strings. A standard soundex string is four characters long, but theSOUNDEX()
function returns an arbitrarily long string. You can useSUBSTRING()
on the result to get a standard soundex string. All non-alphabetic characters instr
are ignored. All international alphabetic characters outside the A-Z range are treated as vowels.mysql>
SELECT SOUNDEX('Hello');
-> 'H400' mysql>SELECT SOUNDEX('Quadratically');
-> 'Q36324'Note: This function implements the original Soundex algorithm, not the more popular enhanced version (also described by D. Knuth). The difference is that original version discards vowels first and duplicates second, whereas the enhanced version discards duplicates first and vowels second.
-
This is the same as
SOUNDEX(
expr1
) = SOUNDEX(expr2
). -
Returns a string consisting of
N
space characters.mysql>
SELECT SPACE(6);
-> ' ' -
SUBSTRING(
str
,pos
),SUBSTRING(
str
FROMpos
),SUBSTRING(
str
,pos
,len
),SUBSTRING(
str
FROMpos
FORlen
)The forms without a
len
argument return a substring from stringstr
starting at positionpos
. The forms with alen
argument return a substringlen
characters long from stringstr
, starting at positionpos
. The forms that useFROM
are standard SQL syntax. It is also possible to use a negative value forpos
. In this case, the beginning of the substring ispos
characters from the end of the string, rather than the beginning. A negative value may be used forpos
in any of the forms of this function.mysql>
SELECT SUBSTRING('Quadratically',5);
-> 'ratically' mysql>SELECT SUBSTRING('foobarbar' FROM 4);
-> 'barbar' mysql>SELECT SUBSTRING('Quadratically',5,6);
-> 'ratica' mysql>SELECT SUBSTRING('Sakila', -3);
-> 'ila' mysql>SELECT SUBSTRING('Sakila', -5, 3);
-> 'aki' mysql>SELECT SUBSTRING('Sakila' FROM -4 FOR 2);
-> 'ki'This function is multi-byte safe.
If
len
is less than 1, the result is the empty string.SUBSTR()
is a synonym forSUBSTRING()
. -
SUBSTRING_INDEX(
str
,delim
,count
)Returns the substring from string
str
beforecount
occurrences of the delimiterdelim
. Ifcount
is positive, everything to the left of the final delimiter (counting from the left) is returned. Ifcount
is negative, everything to the right of the final delimiter (counting from the right) is returned.SUBSTRING_INDEX()
performs a case-sensitive match when searching fordelim
.mysql>
SELECT SUBSTRING_INDEX('www.mysql.com', '.', 2);
-> 'www.mysql' mysql>SELECT SUBSTRING_INDEX('www.mysql.com', '.', -2);
-> 'mysql.com'This function is multi-byte safe.
-
TRIM([{BOTH | LEADING | TRAILING} [
remstr
] FROM]str
),TRIM([
remstr
FROM]str
)Returns the string
str
with allremstr
prefixes or suffixes removed. If none of the specifiersBOTH
,LEADING
, orTRAILING
is given,BOTH
is assumed.remstr
is optional and, if not specified, spaces are removed.mysql>
SELECT TRIM(' bar ');
-> 'bar' mysql>SELECT TRIM(LEADING 'x' FROM 'xxxbarxxx');
-> 'barxxx' mysql>SELECT TRIM(BOTH 'x' FROM 'xxxbarxxx');
-> 'bar' mysql>SELECT TRIM(TRAILING 'xyz' FROM 'barxxyz');
-> 'barx'This function is multi-byte safe.
-
UCASE()
is a synonym forUPPER()
. -
Performs the inverse operation of
HEX(
str
). That is, it interprets each pair of hexadecimal digits in the argument as a number and converts it to the character represented by the number. The resulting characters are returned as a binary string.mysql>
SELECT UNHEX('4D7953514C');
-> 'MySQL' mysql>SELECT 0x4D7953514C;
-> 'MySQL' mysql>SELECT UNHEX(HEX('string'));
-> 'string' mysql>SELECT HEX(UNHEX('1267'));
-> '1267' -
Returns the string
str
with all characters changed to uppercase according to the current character set mapping. The default islatin1
(cp1252 West European).mysql>
SELECT UPPER('Hej');
-> 'HEJ'This function is multi-byte safe.
If a string function is given a binary string as an argument, the resulting string is also a binary string. A number converted to a string is treated as a binary string. This affects only comparisons.
Normally, if any expression in a string comparison is case sensitive, the comparison is performed in case-sensitive fashion.
-
expr
LIKEpat
[ESCAPE 'escape_char
']Pattern matching using SQL simple regular expression comparison. Returns
1
(TRUE
) or0
(FALSE
). If eitherexpr
orpat
isNULL
, the result isNULL
.The pattern need not be a literal string. For example, it can be specified as a string expression or table column.
Per the SQL standard,
LIKE
performs matching on a per-character basis, thus it can produce results different from the=
comparison operator:mysql>
SELECT 'ä' LIKE 'ae' COLLATE latin1_german2_ci;
+-----------------------------------------+ | 'ä' LIKE 'ae' COLLATE latin1_german2_ci | +-----------------------------------------+ | 0 | +-----------------------------------------+ mysql>SELECT 'ä' = 'ae' COLLATE latin1_german2_ci;
+--------------------------------------+ | 'ä' = 'ae' COLLATE latin1_german2_ci | +--------------------------------------+ | 1 | +--------------------------------------+With
LIKE
you can use the following two wildcard characters in the pattern:Character Description %
Matches any number of characters, even zero characters _
Matches exactly one character mysql>
SELECT 'David!' LIKE 'David_';
-> 1 mysql>SELECT 'David!' LIKE '%D%v%';
-> 1To test for literal instances of a wildcard character, precede it by the escape character. If you do not specify the
ESCAPE
character, ‘\
’ is assumed.String Description \%
Matches one ‘ %
’ character\_
Matches one ‘ _
’ charactermysql>
SELECT 'David!' LIKE 'David\_';
-> 0 mysql>SELECT 'David_' LIKE 'David\_';
-> 1To specify a different escape character, use the
ESCAPE
clause:mysql>
SELECT 'David_' LIKE 'David|_' ESCAPE '|';
-> 1The escape sequence should be empty or one character long. As of MySQL 5.0.16, if the
NO_BACKSLASH_ESCAPES
SQL mode is enabled, the sequence cannot be empty.The following two statements illustrate that string comparisons are not case sensitive unless one of the operands is a binary string:
mysql>
SELECT 'abc' LIKE 'ABC';
-> 1 mysql>SELECT 'abc' LIKE BINARY 'ABC';
-> 0In MySQL,
LIKE
is allowed on numeric expressions. (This is an extension to the standard SQLLIKE
.)mysql>
SELECT 10 LIKE '1%';
-> 1Note: Because MySQL uses C escape syntax in strings (for example, ‘
\n
’ to represent a newline character), you must double any ‘\
’ that you use inLIKE
strings. For example, to search for ‘\n
’, specify it as ‘\\n
’. To search for ‘\
’, specify it as ‘\\\\
’; this is because the backslashes are stripped once by the parser and again when the pattern match is made, leaving a single backslash to be matched against. (Exception: At the end of the pattern string, backslash can be specified as ‘\\
’. At the end of the string, backslash stands for itself because there is nothing following to escape.) -
expr
NOT LIKEpat
[ESCAPE 'escape_char
']This is the same as
NOT (
expr
LIKEpat
[ESCAPE 'escape_char
']). -
expr
NOT REGEXPpat
,expr
NOT RLIKEpat
This is the same as
NOT (
expr
REGEXPpat
). -
expr
REGEXPpat
expr
RLIKEpat
Performs a pattern match of a string expression
expr
against a patternpat
. The pattern can be an extended regular expression. The syntax for regular expressions is discussed in Appendix G, Regular Expressions. Returns1
ifexpr
matchespat
; otherwise it returns0
. If eitherexpr
orpat
isNULL
, the result isNULL
.RLIKE
is a synonym forREGEXP
, provided formSQL
compatibility.The pattern need not be a literal string. For example, it can be specified as a string expression or table column.
Note: Because MySQL uses the C escape syntax in strings (for example, ‘
\n
’ to represent the newline character), you must double any ‘\
’ that you use in yourREGEXP
strings.REGEXP
is not case sensitive, except when used with binary strings.mysql>
SELECT 'Monty!' REGEXP 'm%y%%';
-> 0 mysql>SELECT 'Monty!' REGEXP '.*';
-> 1 mysql>SELECT 'new*\n*line' REGEXP 'new\\*.\\*line';
-> 1 mysql>SELECT 'a' REGEXP 'A', 'a' REGEXP BINARY 'A';
-> 1 0 mysql>SELECT 'a' REGEXP '^[a-d]';
-> 1REGEXP
andRLIKE
use the current character set when deciding the type of a character. The default islatin1
(cp1252 West European). Warning: These operators are not multi-byte safe. -
STRCMP()
returns0
if the strings are the same,-1
if the first argument is smaller than the second according to the current sort order, and1
otherwise.mysql>
SELECT STRCMP('text', 'text2');
-> -1 mysql>SELECT STRCMP('text2', 'text');
-> 1 mysql>SELECT STRCMP('text', 'text');
-> 0STRCMP()
uses the current character set when performing comparisons. This makes the default comparison behavior case insensitive unless one or both of the operands are binary strings.