Table 12.7 String Operators
| Name | Description |
|---|---|
ASCII() | Return numeric value of left-most character |
BIN() | Return a string containing binary representation of a number |
BIT_LENGTH() | Return length of argument in bits |
CHAR() | Return the character for each integer passed |
CHAR_LENGTH() | Return number of characters in argument |
CHARACTER_LENGTH() | Synonym for CHAR_LENGTH() |
CONCAT() | Return concatenated string |
CONCAT_WS() | Return concatenate with separator |
ELT() | Return string at index number |
EXPORT_SET() | Return a string such that for every bit set in the value bits, you get an on string and for every unset bit, you get an off string |
FIELD() | Return the index (position) of the first argument in the subsequent arguments |
FIND_IN_SET() | Return the index position of the first argument within the second argument |
FORMAT() | Return a number formatted to specified number of decimal places |
FROM_BASE64() | Decode to a base-64 string and return result |
HEX() | Return a hexadecimal representation of a decimal or string value |
INSERT() | Insert a substring at the specified position up to the specified number of characters |
INSTR() | Return the index of the first occurrence of substring |
LCASE() | Synonym for LOWER() |
LEFT() | Return the leftmost number of characters as specified |
LENGTH() | Return the length of a string in bytes |
LIKE | Simple pattern matching |
LOAD_FILE() | Load the named file |
LOCATE() | Return the position of the first occurrence of substring |
LOWER() | Return the argument in lowercase |
LPAD() | Return the string argument, left-padded with the specified string |
LTRIM() | Remove leading spaces |
MAKE_SET() | Return a set of comma-separated strings that have the corresponding bit in bits set |
MATCH | Perform full-text search |
MID() | Return a substring starting from the specified position |
NOT LIKE | Negation of simple pattern matching |
NOT REGEXP | Negation of REGEXP |
OCT() | Return a string containing octal representation of a number |
OCTET_LENGTH() | Synonym for LENGTH() |
ORD() | Return character code for leftmost character of the argument |
POSITION() | Synonym for LOCATE() |
QUOTE() | Escape the argument for use in an SQL statement |
REGEXP | Pattern matching using regular expressions |
REPEAT() | Repeat a string the specified number of times |
REPLACE() | Replace occurrences of a specified string |
REVERSE() | Reverse the characters in a string |
RIGHT() | Return the specified rightmost number of characters |
RLIKE | Synonym for REGEXP |
RPAD() | Append string the specified number of times |
RTRIM() | Remove trailing spaces |
SOUNDEX() | Return a soundex string |
SOUNDS LIKE | Compare sounds |
SPACE() | Return a string of the specified number of spaces |
STRCMP() | Compare two strings |
SUBSTR() | Return the substring as specified |
SUBSTRING() | Return the substring as specified |
SUBSTRING_INDEX() | Return a substring from a string before the specified number of occurrences of the delimiter |
TO_BASE64() | Return the argument converted to a base-64 string |
TRIM() | Remove leading and trailing spaces |
UCASE() | Synonym for UPPER() |
UNHEX() | Return a string containing hex representation of a number |
UPPER() | Convert to uppercase |
WEIGHT_STRING() | Return the weight string for a string |
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 8.12.2, “Tuning Server Parameters”.
For functions that operate on string positions, the first position is numbered 1.
For functions that take length arguments, noninteger arguments are rounded to the nearest integer.
Returns the numeric value of the leftmost character of the string
str. Returns0ifstris the empty string. ReturnsNULLifstrisNULL.ASCII()works for 8-bit characters.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, whereNis a longlong (BIGINT) number. This is equivalent toCONV(. ReturnsN,10,2)NULLifNisNULL.mysql>
SELECT BIN(12);-> '1100'Returns the length of the string
strin bits.mysql>
SELECT BIT_LENGTH('text');-> 32CHAR(N,... [USINGcharset_name])CHAR()interprets each argumentNas an integer and returns a string consisting of the characters given by the code values of those integers.NULLvalues are skipped.mysql>
SELECT CHAR(77,121,83,81,'76');-> 'MySQL' mysql>SELECT CHAR(77,77.3,'77.3');-> 'MMM'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 optionalUSINGclause:mysql>
SELECT CHARSET(CHAR(X'65')), CHARSET(CHAR(X'65' USING utf8));+----------------------+---------------------------------+ | CHARSET(CHAR(X'65')) | CHARSET(CHAR(X'65' USING utf8)) | +----------------------+---------------------------------+ | binary | utf8 | +----------------------+---------------------------------+If
USINGis 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.Returns the length of the string
str, measured in characters. A multibyte character counts as a single character. This means that for a string containing five 2-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 nonbinary strings, the result is a nonbinary string. If the arguments include any binary strings, the result is a binary string. A numeric argument is converted to its equivalent nonbinary string form.
CONCAT()returnsNULLif any argument isNULL.mysql>
SELECT CONCAT('My', 'S', 'QL');-> 'MySQL' mysql>SELECT CONCAT('My', NULL, 'QL');-> NULL mysql>SELECT CONCAT(14.3);-> '14.3'For quoted strings, concatenation can be performed by placing the strings next to each other:
mysql>
SELECT 'My' 'S' 'QL';-> 'MySQL'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 anyNULLvalues after the separator argument.ELT()returns theNth element of the list of strings:str1ifN=1,str2ifN=2, and so on. ReturnsNULLifNis less than1or 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 anonstring and for every bit not set in the value, you get anoffstring. Bits inbitsare examined from right to left (from low-order to high-order bits). Strings are added to the result from left to right, separated by theseparatorstring (the default being the comma character “,”). The number of bits examined is given bynumber_of_bits, which has a default of 64 if not specified.number_of_bitsis silently clipped to 64 if larger than 64. It is treated as an unsigned integer, so a value of −1 is effectively the same as 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
strin thestr1,str2,str3,...list. Returns0ifstris 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
strisNULL, the return value is0becauseNULLfails 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');-> 0Returns a value in the range of 1 to
Nif the stringstris in the string liststrlistconsisting ofNsubstrings. 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. Returns0ifstris not instrlistor ifstrlistis the empty string. ReturnsNULLif 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');-> 2Formats the number
Xto a format like'#,###,###.##', rounded toDdecimal places, and returns the result as a string. IfDis0, the result has no decimal point or fractional part.The optional third parameter enables a locale to be specified to be used for the result number's decimal point, thousands separator, and grouping between separators. Permissible locale values are the same as the legal values for the
lc_time_namessystem variable (see Section 10.7, “MySQL Server Locale Support”). If no locale is specified, the default is'en_US'.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' mysql>SELECT FORMAT(12332.2,2,'de_DE');-> '12.332,20'Takes a string encoded with the base-64 encoded rules used by
TO_BASE64()and returns the decoded result as a binary string. The result isNULLif the argument isNULLor not a valid base-64 string. See the description ofTO_BASE64()for details about the encoding and decoding rules.This function was added in MySQL 5.6.1.
mysql>
SELECT TO_BASE64('abc'), FROM_BASE64(TO_BASE64('abc'));-> 'JWJj', 'abc'For a string argument
str,HEX()returns a hexadecimal string representation ofstrwhere each byte of each character instris converted to two hexadecimal digits. (Multibyte characters therefore become more than two digits.) The inverse of this operation is performed by theUNHEX()function.For a numeric argument
N,HEX()returns a hexadecimal string representation of the value ofNtreated as a longlong (BIGINT) number. This is equivalent toCONV(. The inverse of this operation is performed byN,10,16)CONV(HEX(.N),16,10)mysql>
SELECT X'616263', HEX('abc'), UNHEX(HEX('abc'));-> 'abc', 616263, 'abc' mysql>SELECT HEX(255), CONV(HEX(255),16,10);-> 'FF', 255Returns the string
str, with the substring beginning at positionposandlencharacters long replaced by the stringnewstr. Returns the original string ifposis not within the length of the string. Replaces the rest of the string from positionposiflenis not within the length of the rest of the string. ReturnsNULLif 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 multibyte safe.
Returns the position of the first occurrence of substring
substrin 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 multibyte safe, and is case sensitive only if at least one argument is a binary string.
Returns the leftmost
lencharacters from the stringstr, orNULLif any argument isNULL.mysql>
SELECT LEFT('foobarbar', 5);-> 'fooba'This function is multibyte safe.
Returns the length of the string
str, measured in bytes. A multibyte character counts as multiple bytes. This means that for a string containing five 2-byte characters,LENGTH()returns10, whereasCHAR_LENGTH()returns5.mysql>
SELECT LENGTH('text');-> 4NoteThe
Length()OpenGIS spatial function is namedGLength()in MySQL.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 path name to the file, and you must have the
FILEprivilege. The file must be readable by all and its size less thanmax_allowed_packetbytes. If thesecure_file_privsystem variable is set to a nonempty directory name, the file to be loaded must be located in that directory.If the file does not exist or cannot be read because one of the preceding conditions is not satisfied, the function returns
NULL.The
character_set_filesystemsystem variable controls interpretation of file names that are given as literal strings.mysql>
UPDATE tSET 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
substrin stringstr. The second syntax returns the position of the first occurrence of substringsubstrin stringstr, starting at positionpos. Returns0ifsubstris not instr.mysql>
SELECT LOCATE('bar', 'foobarbar');-> 4 mysql>SELECT LOCATE('xbar', 'foobar');-> 0 mysql>SELECT LOCATE('bar', 'foobarbar', 5);-> 7This function is multibyte safe, and is case-sensitive only if at least one argument is a binary string.
Returns the string
strwith all characters changed to lowercase according to the current character set mapping. The default islatin1(cp1252 West European).mysql>
SELECT LOWER('QUADRATICALLY');-> 'quadratically'LOWER()(andUPPER()) are ineffective when applied to binary strings (BINARY,VARBINARY,BLOB). To perform lettercase conversion, convert the string to a nonbinary string:mysql>
SET @str = BINARY 'New York';mysql>SELECT LOWER(@str), LOWER(CONVERT(@str USING latin1));+-------------+-----------------------------------+ | LOWER(@str) | LOWER(CONVERT(@str USING latin1)) | +-------------+-----------------------------------+ | New York | new york | +-------------+-----------------------------------+For Unicode character sets,
LOWER()andUPPER()work accounting to Unicode Collation Algorithm (UCA) 5.2.0 forcollations and for language-specific collations that are derived from them. For other Unicode collations,xxx_unicode_520_ciLOWER()andUPPER()work accounting to Unicode Collation Algorithm (UCA) 4.0.0. See Section 10.1.15.1, “Unicode Character Sets”.This function is multibyte safe.
Returns the string
str, left-padded with the stringpadstrto a length oflencharacters. Ifstris longer thanlen, the return value is shortened tolencharacters.mysql>
SELECT LPAD('hi',4,'??');-> '??hi' mysql>SELECT LPAD('hi',1,'??');-> 'h'Returns the string
strwith leading space characters removed.mysql>
SELECT LTRIM(' barbar');-> 'barbar'This function is multibyte safe.
Returns a set value (a string containing substrings separated by “
,” characters) consisting of the strings that have the corresponding bit inbitsset.str1corresponds to bit 0,str2to bit 1, and so on.NULLvalues 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(is a synonym forstr,pos,len)SUBSTRING(.str,pos,len)Returns a string representation of the octal value of
N, whereNis a longlong (BIGINT) number. This is equivalent toCONV(. ReturnsN,10,8)NULLifNisNULL.mysql>
SELECT OCT(12);-> '14'OCTET_LENGTH()is a synonym forLENGTH().If the leftmost character of the string
stris a multibyte 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 multibyte character,
ORD()returns the same value as theASCII()function.mysql>
SELECT ORD('2');-> 50POSITION(is a synonym forsubstrINstr)LOCATE(.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 quotation marks and with each instance of backslash (“
\”), single quote (“'”), ASCIINUL, and Control+Z preceded by a backslash. If the argument isNULL, the return value is the word “NULL” without enclosing single quotation marks.mysql>
SELECT QUOTE('Don\'t!');-> 'Don\'t!' mysql>SELECT QUOTE(NULL);-> NULLFor comparison, see the quoting rules for literal strings and within the C API in Section 9.1.1, “String Literals”, and Section 23.8.7.54, “mysql_real_escape_string()”.
Returns a string consisting of the string
strrepeatedcounttimes. Ifcountis less than 1, returns an empty string. ReturnsNULLifstrorcountareNULL.mysql>
SELECT REPEAT('MySQL', 3);-> 'MySQLMySQLMySQL'Returns the string
strwith all occurrences of the stringfrom_strreplaced 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 multibyte safe.
Returns the string
strwith the order of the characters reversed.mysql>
SELECT REVERSE('abc');-> 'cba'This function is multibyte safe.
Returns the rightmost
lencharacters from the stringstr, orNULLif any argument isNULL.mysql>
SELECT RIGHT('foobarbar', 4);-> 'rbar'This function is multibyte safe.
Returns the string
str, right-padded with the stringpadstrto a length oflencharacters. Ifstris longer thanlen, the return value is shortened tolencharacters.mysql>
SELECT RPAD('hi',5,'?');-> 'hi???' mysql>SELECT RPAD('hi',1,'?');-> 'h'This function is multibyte safe.
Returns the string
strwith trailing space characters removed.mysql>
SELECT RTRIM('barbar ');-> 'barbar'This function is multibyte 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 nonalphabetic characters instrare ignored. All international alphabetic characters outside the A-Z range are treated as vowels.ImportantWhen using
SOUNDEX(), you should be aware of the following limitations:This function, as currently implemented, is intended to work well with strings that are in the English language only. Strings in other languages may not produce reliable results.
This function is not guaranteed to provide consistent results with strings that use multibyte character sets, including
utf-8.We hope to remove these limitations in a future release. See Bug #22638 for more information.
mysql>
SELECT SOUNDEX('Hello');-> 'H400' mysql>SELECT SOUNDEX('Quadratically');-> 'Q36324'NoteThis 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
Nspace characters.mysql>
SELECT SPACE(6);-> ' 'SUBSTR(,str,pos)SUBSTR(,strFROMpos)SUBSTR(,str,pos,len)SUBSTR(strFROMposFORlen)SUBSTR()is a synonym forSUBSTRING().SUBSTRING(,str,pos)SUBSTRING(,strFROMpos)SUBSTRING(,str,pos,len)SUBSTRING(strFROMposFORlen)The forms without a
lenargument return a substring from stringstrstarting at positionpos. The forms with alenargument return a substringlencharacters long from stringstr, starting at positionpos. The forms that useFROMare standard SQL syntax. It is also possible to use a negative value forpos. In this case, the beginning of the substring isposcharacters from the end of the string, rather than the beginning. A negative value may be used forposin any of the forms of this function.For all forms of
SUBSTRING(), the position of the first character in the string from which the substring is to be extracted is reckoned as1.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 multibyte safe.
If
lenis less than 1, the result is the empty string.SUBSTRING_INDEX(str,delim,count)Returns the substring from string
strbeforecountoccurrences of the delimiterdelim. Ifcountis positive, everything to the left of the final delimiter (counting from the left) is returned. Ifcountis 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 multibyte safe.
Converts the string argument to base-64 encoded form and returns the result as a character string with the connection character set and collation. If the argument is not a string, it is converted to a string before conversion takes place. The result is
NULLif the argument isNULL. Base-64 encoded strings can be decoded using theFROM_BASE64()function.This function was added in MySQL 5.6.1.
mysql>
SELECT TO_BASE64('abc'), FROM_BASE64(TO_BASE64('abc'));-> 'JWJj', 'abc'Different base-64 encoding schemes exist. These are the encoding and decoding rules used by
TO_BASE64()andFROM_BASE64():The encoding for alphabet value 62 is
'+'.The encoding for alphabet value 63 is
'/'.Encoded output consists of groups of 4 printable characters. Each 3 bytes of the input data are encoded using 4 characters. If the last group is incomplete, it is padded with
'='characters to a length of 4.A newline is added after each 76 characters of encoded output to divide long output into multiple lines.
Decoding recognizes and ignores newline, carriage return, tab, and space.
TRIM([{BOTH | LEADING | TRAILING} [,remstr] FROM]str)TRIM([remstrFROM]str)Returns the string
strwith allremstrprefixes or suffixes removed. If none of the specifiersBOTH,LEADING, orTRAILINGis given,BOTHis assumed.remstris 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 multibyte safe.
For a string argument
str,UNHEX(interprets each pair of characters in the argument as a hexadecimal number and converts it to the byte represented by the number. The return value is a binary string.str)mysql>
SELECT UNHEX('4D7953514C');-> 'MySQL' mysql>SELECT X'4D7953514C';-> 'MySQL' mysql>SELECT UNHEX(HEX('string'));-> 'string' mysql>SELECT HEX(UNHEX('1267'));-> '1267'The characters in the argument string must be legal hexadecimal digits:
'0'..'9','A'..'F','a'..'f'. If the argument contains any nonhexadecimal digits, the result isNULL:mysql>
SELECT UNHEX('GG');+-------------+ | UNHEX('GG') | +-------------+ | NULL | +-------------+A
NULLresult can occur if the argument toUNHEX()is aBINARYcolumn, because values are padded with 0x00 bytes when stored but those bytes are not stripped on retrieval. For example,'41'is stored into aCHAR(3)column as'41 'and retrieved as'41'(with the trailing pad space stripped), soUNHEX()for the column value returns'A'. By contrast'41'is stored into aBINARY(3)column as'41\0'and retrieved as'41\0'(with the trailing pad0x00byte not stripped).'\0'is not a legal hexadecimal digit, soUNHEX()for the column value returnsNULL.For a numeric argument
N, the inverse ofHEX(is not performed byN)UNHEX(). UseCONV(HEX(instead. See the description ofN),16,10)HEX().Returns the string
strwith all characters changed to uppercase according to the current character set mapping. The default islatin1(cp1252 West European).mysql>
SELECT UPPER('Hej');-> 'HEJ'See the description of
LOWER()for information that also applies toUPPER(). This included information about how to perform lettercase conversion of binary strings (BINARY,VARBINARY,BLOB) for which these functions are ineffective, and information about case folding for Unicode character sets.This function is multibyte safe.
WEIGHT_STRING(str[AS {CHAR|BINARY}(N)] [LEVELlevels] [flags])levels:N[ASC|DESC|REVERSE] [,N[ASC|DESC|REVERSE]] ...This function returns the weight string for the input string. The return value is a binary string that represents the sorting and comparison value of the string. It has these properties:
If
WEIGHT_STRING(=str1)WEIGHT_STRING(, thenstr2)(str1=str2str1andstr2are considered equal)If
WEIGHT_STRING(<str1)WEIGHT_STRING(, thenstr2)(str1<str2str1sorts beforestr2)
WEIGHT_STRING()can be used for testing and debugging of collations, especially if you are adding a new collation. See Section 10.4, “Adding a Collation to a Character Set”.The input string,
str, is a string expression. If the input is a nonbinary (character) string such as aCHAR,VARCHAR, orTEXTvalue, the return value contains the collation weights for the string. If the input is a binary (byte) string such as aBINARY,VARBINARY, orBLOBvalue, the return value is the same as the input (the weight for each byte in a binary string is the byte value). If the input isNULL,WEIGHT_STRING()returnsNULL.Examples:
mysql>
SET @s = _latin1 'AB' COLLATE latin1_swedish_ci;mysql>SELECT @s, HEX(@s), HEX(WEIGHT_STRING(@s));+------+---------+------------------------+ | @s | HEX(@s) | HEX(WEIGHT_STRING(@s)) | +------+---------+------------------------+ | AB | 4142 | 4142 | +------+---------+------------------------+mysql>
SET @s = _latin1 'ab' COLLATE latin1_swedish_ci;mysql>SELECT @s, HEX(@s), HEX(WEIGHT_STRING(@s));+------+---------+------------------------+ | @s | HEX(@s) | HEX(WEIGHT_STRING(@s)) | +------+---------+------------------------+ | ab | 6162 | 4142 | +------+---------+------------------------+mysql>
SET @s = CAST('AB' AS BINARY);mysql>SELECT @s, HEX(@s), HEX(WEIGHT_STRING(@s));+------+---------+------------------------+ | @s | HEX(@s) | HEX(WEIGHT_STRING(@s)) | +------+---------+------------------------+ | AB | 4142 | 4142 | +------+---------+------------------------+mysql>
SET @s = CAST('ab' AS BINARY);mysql>SELECT @s, HEX(@s), HEX(WEIGHT_STRING(@s));+------+---------+------------------------+ | @s | HEX(@s) | HEX(WEIGHT_STRING(@s)) | +------+---------+------------------------+ | ab | 6162 | 6162 | +------+---------+------------------------+The preceding examples use
HEX()to display theWEIGHT_STRING()result. Because the result is a binary value,HEX()can be especially useful when the result contains nonprinting values, to display it in printable form:mysql>
SET @s = CONVERT(X'C39F' USING utf8) COLLATE utf8_czech_ci;mysql>SELECT HEX(WEIGHT_STRING(@s));+------------------------+ | HEX(WEIGHT_STRING(@s)) | +------------------------+ | 0FEA0FEA | +------------------------+For non-
NULLreturn values, the data type of the value isVARBINARYif its length is within the maximum length forVARBINARY, otherwise the data type isBLOB.The
ASclause may be given to cast the input string to a nonbinary or binary string and to force it to a given length:AS CHAR(casts the string to a nonbinary string and pads it on the right with spaces to a length ofN)Ncharacters.Nmust be at least 1. IfNis less than the length of the input string, the string is truncated toNcharacters. No warning occurs for truncation.AS BINARY(is similar but casts the string to a binary string,N)Nis measured in bytes (not characters), and padding uses0x00bytes (not spaces).
mysql>
SELECT HEX(WEIGHT_STRING('ab' AS CHAR(4)));+-------------------------------------+ | HEX(WEIGHT_STRING('ab' AS CHAR(4))) | +-------------------------------------+ | 41422020 | +-------------------------------------+mysql>
SELECT HEX(WEIGHT_STRING('ab' AS BINARY(4)));+---------------------------------------+ | HEX(WEIGHT_STRING('ab' AS BINARY(4))) | +---------------------------------------+ | 61620000 | +---------------------------------------+The
LEVELclause may be given to specify that the return value should contain weights for specific collation levels.The
levelsspecifier following theLEVELkeyword may be given either as a list of one or more integers separated by commas, or as a range of two integers separated by a dash. Whitespace around the punctuation characters does not matter.Examples:
LEVEL 1 LEVEL 2, 3, 5 LEVEL 1-3
Any level less than 1 is treated as 1. Any level greater than the maximum for the input string collation is treated as maximum for the collation. The maximum varies per collation, but is never greater than 6.
In a list of levels, levels must be given in increasing order. In a range of levels, if the second number is less than the first, it is treated as the first number (for example, 4-2 is the same as 4-4).
If the
LEVELclause is omitted, MySQL assumesLEVEL 1 -, wheremaxmaxis the maximum level for the collation.If
LEVELis specified using list syntax (not range syntax), any level number can be followed by these modifiers:ASC: Return the weights without modification. This is the default.DESC: Return bitwise-inverted weights (for example,0x78f0 DESC=0x870f).REVERSE: Return the weights in reverse order (that is,the weights for the reversed string, with the first character last and the last first).
Examples:
mysql>
SELECT HEX(WEIGHT_STRING(0x007fff LEVEL 1));+--------------------------------------+ | HEX(WEIGHT_STRING(0x007fff LEVEL 1)) | +--------------------------------------+ | 007FFF | +--------------------------------------+mysql>
SELECT HEX(WEIGHT_STRING(0x007fff LEVEL 1 DESC));+-------------------------------------------+ | HEX(WEIGHT_STRING(0x007fff LEVEL 1 DESC)) | +-------------------------------------------+ | FF8000 | +-------------------------------------------+mysql>
SELECT HEX(WEIGHT_STRING(0x007fff LEVEL 1 REVERSE));+----------------------------------------------+ | HEX(WEIGHT_STRING(0x007fff LEVEL 1 REVERSE)) | +----------------------------------------------+ | FF7F00 | +----------------------------------------------+mysql>
SELECT HEX(WEIGHT_STRING(0x007fff LEVEL 1 DESC REVERSE));+---------------------------------------------------+ | HEX(WEIGHT_STRING(0x007fff LEVEL 1 DESC REVERSE)) | +---------------------------------------------------+ | 0080FF | +---------------------------------------------------+The
flagsclause currently is unused.
ORDER BY
CAST(SUBSTRING(
Host,
1,
LOCATE('.', Host) - 1)
AS UNSIGNED),
CAST(SUBSTRING(
Host,
LOCATE('.', Host) + 1,
LOCATE('.', Host, LOCATE('.', Host) + 1)
- LOCATE('.', Host) - 1)
AS UNSIGNED),
CAST(SUBSTRING(
Host,
LOCATE('.', Host, LOCATE('.', Host) + 1) + 1,
LOCATE('.', Host,
LOCATE('.', Host, LOCATE('.', Host) + 1) + 1)
- LOCATE('.', Host, LOCATE('.', Host) + 1) - 1)
AS UNSIGNED),
CAST(SUBSTRING(
Host,
LOCATE('.', Host, LOCATE('.', Host,
LOCATE('.', Host) + 1) + 1) + 1,
3)
AS UNSIGNED)
The following formula can be used to extract the Nth item in a delimited list, in this case the 3rd item "ccccc" in the example comma separated list.
select replace(substring(substring_index('aaa,bbbb,ccccc', ',', 3), length(substring_index('aaa,bbbb,ccccc', ',', 3 - 1)) + 1), ',', '') ITEM3
The above formula does not need the first item to be handled as a special case and returns empty strings correctly when the item count is less than the position requested.
More on this and related matters can be found at http://www.kanolife.com/escape/2006/03/mysql-string-splitter.html
SELECT
`ip` ,
SUBSTRING_INDEX( `ip` , '.', 1 ) AS a,
SUBSTRING_INDEX(SUBSTRING_INDEX( `ip` , '.', 2 ),'.',-1) AS b,
SUBSTRING_INDEX(SUBSTRING_INDEX( `ip` , '.', -2 ),'.',1) AS c,
SUBSTRING_INDEX( `ip` , '.', -1 ) AS d
FROM log_table
SELECT DISTINCT REVERSE(LEFT(REVERSE(email),LOCATE('@',REVERSE(email)) - 1)) AS domain FROM table ORDER BY domain
Reverses email, counts the characters from left minus the @. Reverses the reverse and returns 'domain.com'.
Perhaps there is a better/fast/easier way, however it's not easily found. So here is mine.
SELECT SUBSTRING_INDEX(email,'@',-1) AS domain FROM TABLE -- returns everything to the right of the rightmost @
SELECT SUBSTRING(email,INSTR(email,'@')+1) AS domain FROM TABLE -- returns everything to the right of the leftmost @
Both will return identical results on email addresses, since they only have one @ in them. I can't believe you didn't think of SUBSTRING_INDEX, even after the previous two comments used it :)
SELECT CONCAT(UPPER(SUBSTRING(firstName, 1, 1)), LOWER(SUBSTRING(firstName FROM 2))) AS properFirstName
returns empty string instead of NULL, so
SET @where_cond = CONCAT_WS(' AND ', @where1, @where2);
SET @sql = CONCAT_WS(' WHERE ', 'SELECT * FROM table', @where_cond);
SELECT @sql;
results in
SELECT * FROM table WHERE
if both @where1 and @where2 are NULL
select RemoteAddress as IP,
( SUBSTRING_INDEX( RemoteAddress, '.', 1 ) * 16777216 +
SUBSTRING_INDEX(SUBSTRING_INDEX( RemoteAddress, '.', 2 ),'.',-1) * 65536 +
SUBSTRING_INDEX(SUBSTRING_INDEX( RemoteAddress, '.', -2 ),'.',1) * 256 +
SUBSTRING_INDEX( RemoteAddress, '.', -1 )
) AS IP2Num
FROM log
;
SELECT ColName, EXPORT_SET(pow(2,round(ColName))-1,'+','-','',70) FROM TableName
This will create an area filled with "+", where the length of each "+" bar equals the number in column ColName in that row.
70 is an upper bound on the values in ColName; change it to match your actual data.
Another problem is that for numbers N > 53, 2^N - 1 equals 2^N because of rounding errors, so you will not see a bar, only a single "+".
delimiter ||
DROP FUNCTION IF EXISTS substrCount||
CREATE FUNCTION substrCount(s VARCHAR(255), ss VARCHAR(255)) RETURNS TINYINT(3) UNSIGNED LANGUAGE SQL NOT DETERMINISTIC READS SQL DATA
BEGIN
DECLARE count TINYINT(3) UNSIGNED;
DECLARE offset TINYINT(3) UNSIGNED;
DECLARE CONTINUE HANDLER FOR SQLSTATE '02000' SET s = NULL;
SET count = 0;
SET offset = 1;
REPEAT
IF NOT ISNULL(s) AND offset > 0 THEN
SET offset = LOCATE(ss, s, offset);
IF offset > 0 THEN
SET count = count + 1;
SET offset = offset + 1;
END IF;
END IF;
UNTIL ISNULL(s) OR offset = 0 END REPEAT;
RETURN count;
END;
delimiter ;
Use like this:
SELECT substrCount('/this/is/a/path', '/') `count`;
`count` would return 4 in this case. Can be used in such cases where you might want to find the "depth" of a path, or for many other uses.
## Count substrings
CREATE FUNCTION substrCount(x varchar(255), delim varchar(12)) returns int
return (length(x)-length(REPLACE(x, delim, '')))/length(delim);
SELECT substrCount('/this/is/a/path', '/') as count;
SELECT substrCount('/this/is/a/path', 'is') as count;
## Split delimited strings
CREATE FUNCTION strSplit(x varchar(255), delim varchar(12), pos int) returns varchar(255)
return replace(substring(substring_index(x, delim, pos), length(substring_index(x, delim, pos - 1)) + 1), delim, '');
select strSplit("aaa,b,cc,d", ',', 2) as second;
select strSplit("a|bb|ccc|dd", '|', 3) as third;
select strSplit("aaa,b,cc,d", ',', 7) as 7th;
## Upper case first letter, UCFIRST or INITCAP
CREATE FUNCTION ucfirst(x varchar(255)) returns varchar(255)
return concat( upper(substring(x,1,1)),lower(substring(x,2)) );
select ucfirst("TEST");
##Or a more complicated example, this will repeat an insert after every nth position.
drop function insert2;
DELIMITER //
CREATE FUNCTION insert2(str text, pos int, delimit varchar(124))
RETURNS text
DETERMINISTIC
BEGIN
DECLARE i INT DEFAULT 1;
DECLARE str_len INT;
DECLARE out_str text default '';
SET str_len=length(str);
WHILE(i<str_len) DO
SET out_str=CONCAT(out_str, SUBSTR(str, i,pos), delimit);
SET i=i+pos;
END WHILE;
-- trim delimiter from end of string
SET out_str=TRIM(trailing delimit from out_str);
RETURN(out_str);
END//
DELIMITER ;
select insert2("ATGCATACAGTTATTTGA", 3, " ") as seq2;
elt(((field1 <=> NULL) + 1),"not null", "null")
evaluating (field1 <=> NULL) returns 0 (zero) if the field is not null and 1 (one) if the field is null. Adding 1 (one) to this result provides positional information that fits what 'elt' expects.
elt will return "not null" (position 1) if the evaluation of ((field1 <=> NULL) + 1) = 1
it will return "null" (position 2) if the evaluation of ((field1 <=> NULL) + 1) = 2
This can be altered to output messages based on any test that I've tried. Just remember that 'elt' returns null or 1 for a comparison so you need to add 1 (one) to that result to be able to choose between different messages.
select left(substring(<columnName>,locate('|',<columnName>)+1),
locate('|',substring(<columnName>,
locate('|',<columnName>)+1))-1)
as '<resultColumnName>' from <table>
delimiter ||
DROP FUNCTION IF EXISTS strip_tags||
CREATE FUNCTION strip_tags( x longtext) RETURNS longtext
LANGUAGE SQL NOT DETERMINISTIC READS SQL DATA
BEGIN
DECLARE sstart INT UNSIGNED;
DECLARE ends INT UNSIGNED;
SET sstart = LOCATE('<', x, 1);
REPEAT
SET ends = LOCATE('>', x, sstart);
SET x = CONCAT(SUBSTRING( x, 1 ,sstart -1) ,SUBSTRING(x, ends +1 )) ;
SET sstart = LOCATE('<', x, 1);
UNTIL sstart < 1 END REPEAT;
return x;
END;
||
delimiter ;
mysql> SELECT strip_tags('<a href="HelloWorld.html"><B>Hi, mate!</B></a>') as strip_tags;
1 row in set (0.00 sec)
The nice part is that with this formula you don't need to distinguish the first and last element of the string and this formula removes just the value_to_remove so if your initial string is: "4,11,34" and the value you want to remove is "4" you'll get "11,34".
UPDATE temp SET string = TRIM(BOTH ',' FROM REPLACE(CONCAT("," , string, ","), CONCAT(",",'value_to_remove', ",") , ',')) WHERE id=1
Oracle version:
select BU, count(line_number) total,
sum(decode(RECERTIFY_FLAG,'Y',1,0)) needed,
sum(decode(RECERTIFY_FLAG,'N',1,0)) not_needed,
sum(decode(RECERTIFY_FLAG,'Y',0,'N',0,1)) not_processed
from isf.isf_analog_line group by bu order by bu
MySql version that gives same results:
select BU, count(line_number) total,
sum(FIND_IN_SET(RECERTIFY_FLAG,'Y')) needed,
sum(FIND_IN_SET(RECERTIFY_FLAG,'N')) not_needed,
sum(FIND_IN_SET(RECERTIFY_FLAG,' ')) not_processed
from isf.isf_analog_line group by bu order by bu
Add your own comment.
DROP FUNCTION IF EXISTS word_count;
CREATE FUNCTION word_count (f_string text(5000)) RETURNS smallint(10)
BEGIN
DECLARE new_string text(5000);
WHILE INSTR(f_string,'<space><space>')>0
DO
SET new_string=(select REPLACE(f_string,'<space><space>','<space>'));
SET f_string=new_string;
END WHILE;
RETURN (select LENGTH(TRIM(f_string))-LENGTH(REPLACE(TRIM(f_string),'<space>',''))+1);
END
//
Here is the result
mysql> select word_count("<space>Balaji<space><space><space> Devarajan<space>") WORD_COUNT;
1 row in set (0.00 sec)
mysql> select word_count(" Balaji Devarajan ") WORD_COUNT;
1 row in set (0.00 sec)
mysql> select word_count("Balaji Devarajan") WORD_COUNT;
1 row in set (0.01 sec)
delimiter //
drop function if exists sub_domain;
CREATE FUNCTION sub_domain (url text(1000)) RETURNS CHAR(50)
BEGIN
DECLARE str1 varchar(10);
DECLARE str2 varchar(10);
SET str1=http : //;
SET str2=https://;
RETURN if(substring_index(substring_index(substring_index(REPLACE(url,str2,str1), '/',3),str1,-1),'.',-1) != 'com',substring_index(substring_index(substring_index(REPLACE(url,str2,str1), '/',3),str1,-1),'.',-3),substring_index(substring_index(substring_index(REPLACE(url,str2,str1), '/',3),str1,-1),'.',-2));
END;
//
mysql> select domain("http : //maps.google.com/maps?hl=en&q=what%20is%20domain%20name&btnG=Google+Search&ie=UTF-8&oe=UTF-8&um=1&sa=N&tab=il") DOMAIN;
1 row in set (0.00 sec)
similarly we can get the sub-domain too.
delimiter //
drop function if exists sub_domain;
CREATE FUNCTION sub_domain (url text(1000)) RETURNS CHAR(50)
BEGIN
DECLARE str1 varchar(10);
DECLARE str2 varchar(10);
SET str1=http : //;
SET str2=https : //;
RETURN if(substring_index(substring_index(substring_index(REPLACE(url,str2,str1), '/',3),str1,-1),'.',-1) != 'com',substring_index(substring_index(substring_index(REPLACE(url,str2,str1), '/',3),str1,-1),'.',-3),substring_index(substring_index(substring_index(REPLACE(url,str2,str1), '/',3),str1,-1),'.',-3));
END;
//
mysql> select sub_domain("http : //maps.google.com/maps?hl=en&q=what%20is%20domain%20name&btnG=Google+Search&ie=UTF-8&oe=UTF-8&um=1&sa=N&tab=il") sub_domain;
1 row in set (0.00 sec)
DELIMITER //
DROP FUNCTION IF EXISTS get_mcv;
CREATE FUNCTION get_mcv (list text(10000)) RETURNS text(1000)
BEGIN
DECLARE cnt int(10);
DECLARE iter_cnt int(10);
DECLARE item text(100);
DECLARE f_item text(100);
DECLARE prv_cnt int(10) default 0;
DECLARE nxt_cnt int(10) default 0;
IF list=' ' THEN
RETURN list;
END IF;
select substrCount(list,',')+1 into cnt;
SET iter_cnt = 1;
while cnt >= iter_cnt
do
select charsplit(list,',',iter_cnt) into item;
select substrCount(concat(',',list,','),concat(',',item,',')) into nxt_cnt;
IF nxt_cnt > prv_cnt THEN
SET prv_cnt = nxt_cnt;
SET f_item = item;
END IF;
set iter_cnt=iter_cnt+1;
end while;
RETURN f_item;
END
//
mysql> select get_mcv("dsfds,dsfds,fdfds,dfdsf,sd,df,df,df,df");
1 row in set (0.02 sec)
This function uses stringSplit and substrCount - thanks to Chris Stubben.
CREATE FUNCTION cs2in(x varchar(255), delim varchar(12)) returns varchar(255) deterministic
BEGIN
DECLARE retstr varchar(255);
DECLARE Valcount INT(10);
DECLARE v1 INT(10);
SET retstr = '';
SET Valcount = substrCount(x,delim)+1;
SET v1=0;
WHILE (v1 < Valcount) DO
SET retstr = concat_ws(',',retstr,quote(stringSplit(x,delim,v1+1)));
SET v1 = v1 + 1;
END WHILE;
SET retstr = CONCAT('(',TRIM(LEADING ',' FROM TRIM(retstr)),')');
RETURN retstr;
END
E.g.
mysql> Select cs2in('1,2,3,4,5',',') as IN_format;
This format is compatible for use in the 'IN' clause.
------------------------------
DELIMITER $$
DROP FUNCTION IF EXISTS `db2`.`diff3`$$
CREATE DEFINER=`root`@`localhost` FUNCTION `diff3`(n1 varchar(50), n2 varchar(50)) RETURNS int(11)
DETERMINISTIC
BEGIN
declare s1 char(1);
declare s2 char(1);
declare s3 int;
declare s4 int;
declare l1 int;
declare diff int;
set l1 = 1;
set diff = 0;
repeat
set s1 = substring(soundex(n1),l1,1);
set s2 = substring(soundex(n2),l1,1);
if s1 = s2 then set diff = diff + 1;
end if;
set l1 = l1 + 1;
until l1 > 4
end repeat;
return diff;
END$$
DELIMITER ;
----------------------
other DBMS have this function and i kinda needed one. so looked and mysql's online docs shows a DIFFERENCE function but that was for GIS apps and isnt current implemented.
just change the "user@hostname" and the "db.function_name" to reflect your info.
returns an INT value from 0 to 4, where 0 means the SOUNDEX of each string doesnt have any same value. 4 means each 4 alphanumeric digit is the same:
select soundex("hello"), soundex("jello")
returns
H400 and J400
so DIFF3("hello", "jello")
returns a 3
while DIFF3("hello","great")
returns a 1
as a stored function, you can do something like:
select firstname from mytable where diff3("joe bob", firstname) > 3
SELECT LPAD(SUBSTRING(`cardnumbercolumn`, -4, 4),LENGTH(`cardnumbercolumn`),'*') FROM table
eg: LPAD(13, 4, '0') returns '0013'
Any numbers that generate more than the number of digits (4 in this case) would be truncated from the left:
eg: LPAD(41278, 4, '0') returns '1278'
SELECT SUBSTRING_INDEX( SUBSTRING_INDEX( 'a|b|c|d|e|f|g|h', '|', index), '|', -1 );
CONCAT(
ASCII(UNHEX(SUBSTRING(yourIP,1,2))), '.',
ASCII(UNHEX(SUBSTRING(yourIP,3,2))), '.',
ASCII(UNHEX(SUBSTRING(yourIP,5,2))), '.',
ASCII(UNHEX(SUBSTRING(yourIP,7,2)))
)
delimiter ||
DROP FUNCTION IF EXISTS locatelast||
CREATE FUNCTION locatelast(s VARCHAR(1000), ss VARCHAR(1000)) RETURNS TINYINT(3) UNSIGNED LANGUAGE SQL NOT DETERMINISTIC READS SQL DATA
BEGIN
DECLARE last TINYINT(3) UNSIGNED;
DECLARE offset TINYINT(3) UNSIGNED;
DECLARE CONTINUE HANDLER FOR SQLSTATE '02000' SET s = NULL;
SET last = 0;
SET offset = 1;
REPEAT
IF NOT ISNULL(s) AND offset > 0 THEN
SET offset = LOCATE(ss, s, offset);
IF offset > 0 THEN
SET last = offset;
SET offset = offset + 1;
END IF;
END IF;
UNTIL ISNULL(s) OR offset = 0 END REPEAT;
RETURN last;
END;
Instead of looping through the string to look for the last occurrence, simply reverse() the string and look for the first occurrence, then substract the found position from the string length:
select @loc:=length(realname) - locate(" ", reverse(realname)) from table
For instance, looking for the last occurrence of a space?
select @string:="A horse with no name" as String, @loc:=length(@string) - locate(" ", reverse(@string))+1 AS lastoccurrence, left(@string, @loc), substr(@string,@loc+1);
where using GROUP_CONCAT.
The default is 8192 (bytes), and if the result is bigger, it will be silently cropped, leading to unexpected results.
Some examples here: http://confronte.com.ar/groupconcat
Example :
SELECT 0 = '';
==> 1
SELECT '0' = '';
==> 0
SELECT CAST(0 AS CHAR) = '';
==> 0
This is common when you want to check user input : if a user inputs a "0" for a field, the check without cast will fail because mysql thinks this is an empty string.
I know the example where it is needed to walk through the input string to find dilimiters but I think this way annoying.
You may use my solution from below which is also keeping the order of substring occurance:
(input string is stored in "input" variable)
CREATE TEMPORARY TABLE temp (id TINYINT NOT NULL auto_increment, val CHAR(20), PRIMARY KEY(id));
SET input=REPLACE(input, ",", "'),('");
SET @dyn_sql=CONCAT("INSERT INTO temp (val) VALUES ('",input,"');");
PREPARE s1 FROM @dyn_sql; EXECUTE s1;
SELECT * FROM temp;
Hope this would help someone :)
That is a great example. Here is how I used a very similar example to find a contact's last name from a contacts database by sub string on the last instance of the space:
SELECT @string:=Full_Name, SUBSTRING(@string, LENGTH(SUBSTRING(REVERSE(@string), LOCATE(" ", REVERSE(@string))-1))) AS Last_Name FROM contacts;
Something that would more elegant would be to have the LOCATE function include a direction option, like:
SELECT SUBSTRING(foo, LOCATE(" ", foo, RIGHT)) AS bar;
try this
update temp set locus=trim(BOTH ' ' from locus)
if you want to find the last occurrence of a particular string, use the tools mysql provides for you:
select reverse( substring( reverse( field ), locate( 'xyz', reverse( field ) )+1 ) )
---
this is way easier to implement and debug
Maybe it will help someone to find it's own and better solutions ;)
CREATE FUNCTION SOUNDEX_SEARCHTEXT( haystack LONGTEXT, needle VARCHAR(40) ) RETURNS INT
BEGIN
DECLARE part VARCHAR(40) DEFAULT SUBSTRING( haystack, 1, LENGTH(needle) );
DECLARE iterator INT DEFAULT 1;
WHILE iterator < LENGTH( haystack )-LENGTH(needle)+1 DO
SET iterator = iterator + 1;
SET part = SUBSTRING( haystack, iterator, LENGTH(needle) );
IF part SOUNDS LIKE needle THEN
RETURN 1;
END IF;
END WHILE;
RETURN 0;
END
Hope it will be usefull - with best regards
DELIMITER $$
DROP FUNCTION IF EXISTS `initcap`$$
CREATE DEFINER=`root`@`%` FUNCTION `initcap`(x varchar(255)) RETURNS varchar(255) CHARSET utf8
begin
set @l_str='';
set @r_str='';
if x REGEXP ' ' then
SELECT SUBSTRING_INDEX(x, ' ',1) into @l_str;
SELECT SUBSTRING_INDEX(x, ' ',-1) into @r_str;
return concat(concat( upper(substring(@l_str,1,1)),lower(substring(@l_str,2))),' ',concat( upper(substring(@r_str,1,1)),lower(substring(@r_str,2))));
else
return concat( upper(substring(x,1,1)),lower(substring(x,2)));
end if;
end$$
DELIMITER ;
Thank you for the hint!
Follow your examples I generate the following statement:
RIGHT(foo, locate(' ', REVERSE(foo))-1) as foo
There are several stored procedures (e.g., see post of Grigory Dmitrenko) to transform
string like 'a,b,c' into something to be used like
....WHERE x IN ('a','b','c').
Here is solution to transform delimited string
into real table. Thus, it can be used further in
JOIN or IN constructs.
Pre-condition -- existence of some table with row count
bigger than elements in string. I will use
3-row table created on-fly by UNION.
mysql> select substring_index(substring_index('a,b,c', ',',@r:=@r+1),',',-1) zxz
from (select @r:=0) x,
(select 'x' xx union select 'v' xx union select 'z' xx) z;
3 rows in set (0.00 sec)
Thanks ben j for double *substring_index* example posted above.
SELECT SUBSTRING(foobar,1,LENGTH(foobar)-3) AS foobar
SELECT SUBSTRING_INDEX(SUBSTRING_INDEX(url,'://',-1),'/',1)
FROM urls
It works for URLs with and without http(s). But doesn't work if you have local URLs without a leading slash like "folder/index.html". In that case it extracts "folder" instead of an empty string.
mysql> select description from catalog;
the list looked all garbled
I used next command to remove it (most, but not all of the rows in the table were contaminated):
mysql> update catalog set description = left(description,length(description) -1) where description like "%^M%";
Please note that to replicate that "^M" you must press <ctrl> and v --though no character will be displayed-- and then <ctrl> and m.
SELECT
REVERSE(SUBSTR(REVERSE(name),INSTR(REVERSE(name),' ')+1)) AS first,
REVERSE(SUBSTR(REVERSE(name),1,INSTR(REVERSE(name),' '))) AS last
FROM table
One minor change, since you are only replacing the one character at the end is, change the where clause to
where description like "%^M";
-- ***********************************
DELIMITER $$
DROP FUNCTION IF EXISTS `initcap` $$
CREATE FUNCTION `initcap`(x char(30)) RETURNS char(30) CHARSET utf8
BEGIN
SET @str='';
SET @l_str='';
WHILE x REGEXP ' ' DO
SELECT SUBSTRING_INDEX(x, ' ', 1) INTO @l_str;
SELECT SUBSTRING(x, LOCATE(' ', x)+1) INTO x;
SELECT CONCAT(@str, ' ', CONCAT(UPPER(SUBSTRING(@l_str,1,1)),LOWER(SUBSTRING(@l_str,2)))) INTO @str;
END WHILE;
RETURN LTRIM(CONCAT(@str, ' ', CONCAT(UPPER(SUBSTRING(x,1,1)),LOWER(SUBSTRING(x,2)))));
END $$
DELIMITER ;
-- ***********************************
One gotcha to note: this method strips out any leading and trailing spaces from the input, which really isn't that big of a deal, but something to keep in mind.
DROP FUNCTION IF EXISTS strSplit;
CREATE FUNCTION strSplit(x varchar(21845), delim varchar(255), pos int) returns varchar(255)
return replace(
replace(
substring_index(x, delim, pos),
substring_index(x, delim, pos - 1),
''
),
delim,
''
);
mysql> select strSplit("あ|ええ|いいい|おおお", '|', 4) as 4th;
instead of using the command:
select replace(
substring_index(field, delim, pos),
substring_index(field, delim, pos - 1),
'')
from table;
you can shorten it to require less modifiying by doing:
select substring_index(
substring_index(field, 'xyz', pos)
, 'xyz', -1)
from table;
that will get the last element of the list of x that were found. which should be the one you want.
hope this helps!
SELECT * from foo
WHERE FIND_IN_SET(col, REPLACE('a, b, c', ' ', '')) != 0;
count of '@' char:
SELECT
stringfield,
LENGTH(stringfield)-LENGTH(REPLACE(stringfield,'@',''))
FROM tablename
CREATE FUNCTION `ucwords`(`string` text) RETURNS text CHARSET latin1
BEGIN
DECLARE final_string text default '';
DECLARE char_index int unsigned default 1;
DECLARE upperchar int unsigned default 1;
IF LENGTH(string)>0 THEN
IF LOCATE(' ',string) > 0 OR LOCATE('.',string) OR LOCATE('(',string) > 0 OR LOCATE('¿',string) THEN
REPEAT
IF upperchar = 1 THEN
SET final_string = CONCAT(final_string,UPPER(SUBSTRING(string,char_index,1)));
SET upperchar = 0;
ELSE
SET final_string = CONCAT(final_string,SUBSTRING(string,char_index,1));
END IF;
IF (SUBSTRING(string,char_index,1) = ' ') OR (SUBSTRING(string,char_index,1) = '.') OR (SUBSTRING(string,char_index,1) = '(') OR (SUBSTRING(string,char_index,1) = '¿') THEN
SET upperchar = 1;
END IF;
SET char_index = char_index + 1;
UNTIL char_index > LENGTH(string)
END REPEAT;
ELSE
SET final_string = CONCAT(UPPER(SUBSTRING(string,1,1)),SUBSTRING(string,2));
END IF;
ELSE
SET final_string = string;
END IF;
RETURN final_string;
END
delimiter $$
--
-- This function will return the first position in p_str where the regexp is true
--
drop function if exists regexPos $$
create function regexPos( p_str TEXT, p_regex varchar(250) ) returns int
BEGIN
declare v_pos int;
declare v_len int;
set v_pos=1;
set v_len=1+char_length( p_str );
while (( substr( p_str, 1, v_pos) REGEXP p_regex)=0 and (v_pos<v_len))
do
set v_pos = v_pos + 1;
end while;
return v_pos-1;
end $$
--
-- This procedure parses p_str into words based on the regular expression p_regex.
-- The simplest usage is call ParseWords( "some string", "[[:space:]]" );
-- this will break the string on spaces.
CREATE procedure ParseWords (IN p_str TEXT, IN p_regex varchar(256))
begin
declare v_startPos int;
declare v_strLen int;
declare v_wordLen int;
set v_startPos=1;
set v_strLen=char_length( p_str )+1;
while ( v_startPos < v_strLen )
do
set v_wordLen = regexPos( substring( p_str, v_startPos ), p_regex );
while (v_wordLen = 0) and ( v_startPos < v_strLen)
do
-- if the wordLen is 0 (zero) then we have a space at the start
-- so remove it and try again.
set v_startPos = v_startPos+1;
set v_wordLen = regexPos( substring( p_str, v_startPos ), p_regex );
end while;
if (v_wordLen > 0)
then
-- we found a word.
-- do something useful here. This example simply prints out the words
-- a real application will probably insert them into a table.
select substring( p_str, v_startPos, v_wordLen );
set v_startPos = v_startPos + v_wordLen +1;
end if;
end while;
end $$
delimiter ;
DELIMITER $$
DROP FUNCTION IF EXISTS `rendpos` $$
CREATE DEFINER=`root`@`localhost` FUNCTION `rendpos`(p_regex varchar(250),p_str TEXT) RETURNS int(11)
BEGIN
declare v_endpos int;
declare v_startpos int;
declare v_len int;
set v_endpos=1;
set v_len=1+char_length( p_str );
while (( substr( p_str, 1, v_endpos) REGEXP p_regex)=0 and (v_endpos<v_len))
do
set v_endpos = v_endpos + 1;
end while;
return v_endpos;
END $$
DELIMITER ;
Here is a quick and dirty find of start position. It will find the minimal match instead of the maximal pattern match. Please feel free to modify this to find the maximal pattern match.
DELIMITER $$
DROP FUNCTION IF EXISTS `rlocate` $$
CREATE DEFINER=`root`@`localhost` FUNCTION `rlocate`(p_regex varchar(250),p_str TEXT, s_startpos int) RETURNS int(11)
BEGIN
declare v_endpos int;
declare v_startpos int;
declare v_len int;
set v_endpos=rendpos(p_regex, p_str, s_startpos);
set v_startpos = v_endpos;
while (( substr( p_str, v_startpos, v_endpos) REGEXP p_regex)=0 and (v_startpos > 0))
do
set v_startpos = v_startpos - 1;
end while;
return v_startpos;
END $$
DELIMITER ;
The extract uses the above two functions, so it will likewise extract the minimal pattern.
DELIMITER $$
DROP FUNCTION IF EXISTS `rextract` $$
CREATE DEFINER=`root`@`localhost` FUNCTION `rextract`(p_regex varchar(250),p_str TEXT, s_startpos int) RETURNS varchar(250) CHARSET latin1
begin
declare startpos int;
declare endpos int;
set startpos = rlocate(p_regex,p_str,s_startpos);
set endpos = rendpos(p_regex,p_str,s_startpos);
return mid(p_str,startpos,endpos-startpos+1);
end $$
DELIMITER ;
http://ionisis.com/?a=WCMS_Page_Display&id=27576001275882717
UPDATE mytable SET city = CONCAT(UCASE(MID(city,1,1)),MID(LCASE(city),2))
So city names PARIS or paris will be changed to Paris.
To work around this limitation, one can use nested IF() functions like this:
IF((col1, col2)=(11,12), 1, IF((col1, col2)=(22,23), 2, 0))
UPDATE table_name AS t SET t.field_name = INSERT(t.field_name, 4, 0, 'redient(s)') WHERE LEFT(t.field_name, 4) = 'Ing:';
This inserts 'edient(s)' between the 'g' and ':' in 'Ing:', giving us 'Ingredient(s):' It also tests t.field_name to see if it is to be updated. This is based on knowing that the first three charters in t.field_name will be 'Ing:' or not, and if it is then we spell it out. You can even expand the spelling in the t.field_name, not just the start or end of it, as this might suggest. Use INSTR(t.field_name, 'str_to_expand'), so it would end up looking like:
UPDATE table_name AS t SET t.field_name = INSERT(t.field_name, INSTR(t.field_name, 'Ing:'), 0, 'redient(s)') WHERE LEFT(t.field_name, 4) = 'Ing:';
If you know that you have the abbreviation in more than just one place within a field (aka column) then just run the command again. In both cases the number zero '0' is the key, it tells the INSERT command not to overwrite any of the following charters, just insert the requested sub-string.
PROCEDURE Insert(IN STR_IN VARCHAR(255), IN ID_IN INT)
BEGIN
declare lang int default LENGTH(STR_IN);
declare sep char default ';';
declare tmpMerge char(255);
declare tmpChar char;
declare loop_done integer default 1;
stringcutter: loop
set tmpChar = substring(STR_IN,loop_done,1);
if tmpChar <> sep then
if isnull(tmpMerge) then set tmpMerge = tmpChar;
else select concat(tmpMerge,tmpChar)into tmpMerge;end if;end if;
if tmpChar = sep then DO WHAT YOU WANT;set tmpMerge = NULL;end if;
set loop_done = loop_done + 1;
if loop_done = lang then leave stringcutter;end if;
end loop stringcutter;
END
DROP PROCEDURE IF EXISTS `SPLIT_STRING`;
DELIMITER |
CREATE PROCEDURE `SPLIT_STRING` (IN `MY_STRING` TEXT, IN `MY_DELIMITER` TEXT)
LANGUAGE SQL
SQL SECURITY INVOKER
BEGIN
#-------------------------------------------------------------------------------
IF NOT ISNULL(MY_STRING) THEN
IF NOT ISNULL(MY_DELIMITER) THEN
#
SET @SS = TRIM(MY_STRING);
SET @DEL = TRIM(MY_DELIMITER);
#
IF LENGTH(@SS) > 0 THEN
IF LENGTH(@DEL) > 0 THEN
#
SET @DP = (SELECT LOCATE(@DEL, @SS, 1));
IF @DP > 0 THEN
#------------------------CREATE TEMP TABLE-----------------------
DROP TABLE IF EXISTS `TEMPORARY_TABLE_OF_SPLIT_STRINGS`;
#
CREATE TEMPORARY TABLE `TEMPORARY_TABLE_OF_SPLIT_STRINGS` (
`SUB_STRING` text CHARACTER SET utf8 COLLATE utf8_general_ci NOT NULL
)
ENGINE=INNODB
CHARACTER SET utf8
COLLATE utf8_general_ci ;
#----------------------------------------------------------------
SET @SS_2 = @SS;
#
REPEAT
#
SET @FIRST_ELEMENT = (SELECT SUBSTRING_INDEX(@SS_2, @DEL, 1));
SET @SS_2 = (SELECT TRIM(LEADING CONCAT(@FIRST_ELEMENT, @DEL) FROM @SS_2));
#
INSERT INTO `TEMPORARY_TABLE_OF_SPLIT_STRINGS` (`SUB_STRING`) VALUES (@FIRST_ELEMENT);
SET @DP = (SELECT LOCATE(@DEL, @SS, @DP + 1));
#
IF @DP = 0 THEN
SET @LAST_ELEMENT = (SELECT SUBSTRING_INDEX(@SS_2, @DEL, -1));
INSERT INTO `TEMPORARY_TABLE_OF_SPLIT_STRINGS` (`SUB_STRING`) VALUES (@LAST_ELEMENT);
END IF;
UNTIL @DP = 0
END REPEAT;
#
SELECT * FROM TEMPORARY_TABLE_OF_SPLIT_STRINGS;
#----------------------------------------------------------------
DROP TABLE IF EXISTS `TEMPORARY_TABLE_OF_SPLIT_STRINGS`;
#----------------------------------------------------------------
ELSE
SELECT NULL;
END IF;
ELSE
SELECT NULL;
END IF;
ELSE
SELECT NULL;
END IF;
ELSE
SELECT NULL;
END IF;
ELSE
SELECT NULL;
END IF;
END; |
DELIMITER ;
Thus split function can be used more than once in the same stored procedure because table have any name.
This is the SP. Excuse me for my bad english :(
DELIMITER $$
CREATE PROCEDURE `SplitString`( IN input TEXT,
IN delimiter VARCHAR(10), IN Table_name VARCHAR(50)
)
SQL SECURITY INVOKER
BEGIN
DECLARE cur_position INT DEFAULT 1 ;
DECLARE remainder TEXT;
DECLARE cur_string VARCHAR(1000);
DECLARE delimiter_length TINYINT UNSIGNED;
set @sql_drop = concat('DROP TEMPORARY TABLE IF EXISTS ',' ',Table_name);
prepare st_drop from @sql_drop;
execute st_drop;
set @sql_create = concat('CREATE TEMPORARY TABLE ' ,Table_name ,' (value VARCHAR(1000) NOT NULL PRIMARY KEY) ENGINE=MEMORY;');
prepare st_create from @sql_create;
execute st_create;
SET remainder = input;
SET delimiter_length = CHAR_LENGTH(delimiter);
WHILE CHAR_LENGTH(remainder) > 0 AND cur_position > 0 DO
SET cur_position = INSTR(remainder, delimiter);
IF cur_position = 0 THEN
SET cur_string = remainder;
ELSE
SET cur_string = LEFT(remainder, cur_position - 1);
END IF;
IF TRIM(cur_string) != '' THEN
set @sql_insert = concat('INSERT INTO ' ,Table_name, ' VALUES (',cur_string,');');
prepare st_insert from @sql_insert;
execute st_insert;
END IF;
SET remainder = SUBSTRING(remainder, cur_position +
delimiter_length);
END WHILE;
END
Here the difference between the string functions LOCATE and FIND_IN_SET is..
1.When using LOCATE for integers use carefully..
example:
If I need to return 1 if 2 is in the set '1,2,3,4,5'.
SELECT IF(LOCATE(2,'1,2,3,4,5,6,7,8,9')>0,1,0);
You know very well it return 1,because the set contains value 2 in given set.
SO it is no problem...
FOR this Example query it returns wrong as we expected...
SELECT IF(LOCATE(2,'11,12,3,4,5,6,7,8,9')>0,1,0);
even though 2 is not available in set,it gives 1.
here LOCATE function takes the set as the STRING not the comma(,) separated value..
In this situation Please use the FIND_IN_SET - which is great function for the comma(,) separated value set.
Now,
SELECT IF(FIND_IN_SET(2,'11,12,3,4,5,6,7,8,9')>0,1,0);
It returns 1 as we expected...
Note:
1.Use LOCATE function for alphabetic strings only..
2.And also use LOCATE for numeric numbers that set contains the numbers only 0,1,2,3,4,5,6,7,8,9
i.e.,
SELECT IF(LOCATE(input,'0,1,2,3,4,5,6,7,8,9')>0,1,0);
input must be any one within 0,1,2,3,4,5,6,7,8,9
Its work nicely.
http://thesocialexpo.com/?a=SUBS_Blog_Display&id=13023741560341786
Here is a patched version because Mysql crashed when I tryied to proceed a NULL value
delimiter ||
DROP FUNCTION IF EXISTS strip_tags||
CREATE FUNCTION strip_tags( x longtext) RETURNS longtext
LANGUAGE SQL NOT DETERMINISTIC READS SQL DATA
BEGIN
DECLARE sstart INT UNSIGNED;
DECLARE ends INT UNSIGNED;
IF x IS NOT NULL THEN
SET sstart = LOCATE('<', x, 1);
REPEAT
SET ends = LOCATE('>', x, sstart);
SET x = CONCAT(SUBSTRING( x, 1 ,sstart -1) ,SUBSTRING(x, ends +1 )) ;
SET sstart = LOCATE('<', x, 1);
UNTIL sstart < 1 END REPEAT;
END IF;
return x;
END;
delimiter ;
mysql> SELECT strip_tags('<a href="HelloWorld.html"><B>Hi, mate!</B></a>') as strip_tags;
DELIMITER $$
DROP FUNCTION IF EXISTS `initcap`$$
CREATE FUNCTION `initcap`(x varchar(255)) RETURNS varchar(255) CHARSET utf8
DETERMINISTIC
begin
set @out_str='';
set @l_str='';
set @r_str='';
set @pos=LOCATE(' ',x);
SELECT x into @r_str;
while (@pos > 0) DO
SELECT SUBSTRING(@r_str,1,@pos-1) into @l_str;
SELECT SUBSTRING(@r_str,@pos+1) into @r_str;
SELECT concat(@out_str,upper(substring(@l_str,1,1)),lower(substring(@l_str,2)),' ') into @out_str;
set @pos=LOCATE(' ',@r_str);
END WHILE;
SELECT concat(@out_str,upper(substring(@r_str,1,1)),lower(substring(@r_str,2))) into @out_str;
return trim(@out_str);
end$$
DELIMITER ;
SELECT CONCAT(SUBSTRING_INDEX(DateMDY, '-', -1), '-', SUBSTRING_INDEX(DateMDY, '-', 2))
Now you can CAST this to a DATE, and then it will ORDER BY or GROUP BY properly. E.g. this takes '11.1.2011' and returns a real DATE of 2011-11-01. As usual I'm sure there are other ways to do this. I was just happy to figure this out without resorting to PHP or Perl.
CAST(CONCAT(SUBSTRING_INDEX(DateMDY, '.', -1), '.', SUBSTRING_INDEX(DateMDY, '.', 2)) AS DATE)
select substring_index(substring_index(json_params_column, 'jsonKey":"', -1), '"', 1) from MyTable;
The table I started with was something like...
id, list_of_types
(champion_1), (mage, fighter, support)
(champion_2), (support, mage)
(champion_3), (tank, support)
and the table I needed was....
id, type
champion_1, mage
champion_1, fighter
champion_1, support
champion_2, support
champion_3, tank
champion_3, support
So I ran...
select tOut.*, replace(substring(substring_index(type, ',', ocur_rank), length(substring_index(type, ',', ocur_rank - 1)) + 1), ',', '')
from (select @num_type := if(@id_check = tY.id, @num_type + 1, 1) as ocur_rank, @id_check := tY.id as id_check, tY.*
from (select LENGTH(list) - length(replace(list, ',', '')) as num_ocur, id, list from item) tX
inner join (select LENGTH(list) - length(replace(list, ',', '')) as num_ocur, id, list from item) tY
inner join (select @num_type := 0, @id_check := 'some_id') tZ) tOut
where ocur_rank <= num_ocur + 1;
Where "id" is just some unique identifier for each field you're splitting up and "list" is the list of separated values. The thought behind the query is to just join a table to itself, rank the rows for each id, then only show rows where the rank is less than the number of occurrences of the separator in the list you're splitting up. The outter most select then shows the value in between the rank and rank + 1 occurrence of the separator in the list.
This may not work if some of the lists don't have any occurrence of the separator.
so if you want to check if the contents of one column are in another column
http://www.edmondscommerce.co.uk/mysql/compare-two-columns-in-mysql/
LOCATE(col1, col2) > 0 -- if "col1" is found in "col2"
OR
LOCATE(col2, col1) > 0 -- if "col2" is found in "col1"
SELECT SUBSTRING_INDEX(email,'@',1) FROM <table> WHERE email REGEXP '@'
SELECT SPLIT_STR('a|bb|ccc|dd', '|', 3) as third;
-Mo
Ex, for the text "0,1,3,5,6", you wanna get the third element. This would do the trick:
select substring_index(substring_index(column,',',3),',',-1) as third;
P.S..: This seems a simplification of the previous example (which I managed to miss)
SELECT *
FROM
`table`
WHERE
`col1` LIKE CONCAT('%', `col2`, '%')
OR col2 LIKE CONCAT('%',`col1`,'%')
Posted by http://www.competenciaperfecta.com/
One of the first search results on another website suggested to use the locate function and if you need the last occurrence, use reverse string before using locate. Then use reverse again to get the correct sting. Just thought I'll post here with the important keywords, so it shows up in search results in case somebody else is looking for the same. HTH
This code updates the column named 'phone_number' in the table called 'user' by concatenating '0' in front of the new phone_number.
The new phone_number is old phone_number minus the first 4 characters or beginning from the 5th character.
The update will only be applied to the records with id between 3 and 30 exclusive.
UPDATE user SET phone_number = CONCAT('0', SUBSTRING(phone_number, 5)) WHERE id > 3 AND id < 30;
See how the code is shorter than the explanation?
Biniam from Ethiopia.
CREATE FUNCTION fn_propercase
(p_string Varchar(254)) RETURNS Varchar
BEGIN
SET @out="";
SET @x = 1;
SET @len = LENGTH(p_string);
/* Always make the 1st char uppercase. Set the flag on. */
SET @uc = 1;
REPEAT
SET @char= MID(p_string,@x,1);
IF @uc=1 THEN
SET @out= CONCAT(@out,UPPER(@char));
ELSE
SET @out= CONCAT(@out,LOWER(@char)) ;
END IF;
/* AFTER the char is written, test whether it is blank
if so, the NEXT char will be uppercase. */
IF @char=" " THEN
SET @uc= 1;
ELSE
SET @uc= 0;
END IF;
SET @x= @x + 1;
UNTIL @x > @len END REPEAT;
RETURN @out;
END
SET @str:='mba,bca,mca,Bed'; # Your Complete String
SET @length:=LENGTH(@str);
SET @limit:=@length-LENGTH(REPLACE(@str,',',''))+1;
SET @pos:=2; # Substring position value
SET @tmp:=REVERSE(SUBSTRING_INDEX(@str,',',@pos));
SELECT IF(@limit>=@pos,
IF(@pos=1,SUBSTRING_INDEX(@str,',',@pos),REVERSE(SUBSTRING(@tmp,1,LOCATE(',',@tmp)-1))),'Not Exist')AS "Required_String"
Cheers!
DROP FUNCTION IF EXISTS str_titlecase;
CREATE FUNCTION str_titlecase (p_string varchar(254)) RETURNS varchar (254)
## by Adrian Humphreys, edited by Durham
## for given string, concatenate Capitalized first letter of
## each given word with Lower Case remainder of word
BEGIN
DECLARE output_string VARCHAR(254) DEFAULT '';
DECLARE temp_string VARCHAR(254);
DECLARE x INT DEFAULT 1; /*tracking variable*/
DECLARE uc INT DEFAULT 1; /*uppercase flag*/
DECLARE input_string_length INT DEFAULT LENGTH(p_string);
IF p_string IS NOT NULL THEN
REPEAT
SET temp_string := MID(p_string,x,1);
IF uc=1 THEN
SET output_string := CONCAT(output_string,UPPER(temp_string));
ELSE
SET output_string := CONCAT(output_string,LOWER(temp_string)) ;
END IF;
/* AFTER the char is written, test whether it is blank
if so, the NEXT char will be uppercase. */
IF temp_string=' ' THEN
SET uc := 1;
ELSE
SET uc := 0;
END IF;
SET x := x + 1;
UNTIL x > input_string_length END REPEAT;
END IF;
RETURN output_string;
END
#########################
## Usage (all lower case input):
select str_titlecase('i am a cat') as title from dual;
## Results:
title
------
I Am A Cat
## Usage (blank string case):
select str_titlecase('') as title from dual;
## Results:
title
------
## Usage (all upper case input):
select str_titlecase('I AM A DOLPHIN') as title from dual;
## Results:
title
------
I Am A Dolphin
## Usage (mixed-case input):
select str_titlecase('I am THE PRODUCT of your IMAGinatioN') as title from dual;
## Results:
title
------
I Am The Product Of Your Imagination
CREATE FUNCTION `hasString`(haystack TINYTEXT, needle TINYTEXT) RETURNS TINYINT(1)
BEGIN
DECLARE needleFound TINYINT(1);
DECLARE inipos INTEGER;
DECLARE endpos INTEGER;
DECLARE maxlen INTEGER;
DECLARE item VARCHAR(100);
DECLARE delim VARCHAR(1);
SET delim = ',';
SET inipos = 1;
SET endpos = 0;
SET needleFound = 0;
SET maxlen = LENGTH(haystack);
REPEAT
SET endpos = LOCATE(delim, haystack, inipos);
SET item = SUBSTR(haystack, inipos, endpos - inipos);
IF inipos = 1 AND endpos = 0 THEN
IF haystack = needle THEN
SET needleFound = 1;
END IF;
SET endpos = maxlen + 100;
ELSE
IF inipos > 1 AND endpos = 0 THEN
SET endpos = maxlen + 50;
ELSE
IF item <> '' AND item IS NOT NULL THEN
IF item=needle THEN
SET needleFound = 1;
END IF;
ELSE
SET inipos = maxlen + 10;
END IF;
END IF;
END IF;
SET inipos = endpos + 1;
UNTIL inipos >= maxlen END REPEAT;
RETURN needleFound;
END
/**
* #1: this way is 10-20% faster than #3 and supports not included indexes otherwise than #2
*
* @example: split('a|bbb|cc', '|', 0) -> 'a'
* @example: split('a|bbb|cc', '|', 1) -> 'bbb'
* @example: split('a|bbb|cc', '|', 2) -> 'cc'
* @example: split('a|bbb|cc', '|', 3) -> ''
*/
substring_index(substring_index(concat(content, delimiter), delimiter, index+1), delimiter, -1);
/**
* #2: faster than #3, but not included index will return last entry
*
* @see: Posted by Mariano Otero on June 22 2012 3:43pm
* @example: split('a|bbb|cc', '|', 0) -> 'a'
* @example: split('a|bbb|cc', '|', 1) -> 'bbb'
* @example: split('a|bbb|cc', '|', 2) -> 'cc'
* @example: split('a|bbb|cc', '|', 3) -> 'cc' (unexpected)
*/
substring_index(substring_index(content, delimiter, index+1), delimiter, -1);
/**
* #3: first introduced split example, supports not included indexes
*
* @see: Posted by Bob Collins on March 17 2006 8:56pm
* @example: split('a|bbb|cc', '|', 0) -> 'a'
* @example: split('a|bbb|cc', '|', 1) -> 'bbb'
* @example: split('a|bbb|cc', '|', 2) -> 'cc'
* @example: split('a|bbb|cc', '|', 3) -> ''
*/
replace(substring(substring_index(content, delimiter, index+1), length(substring_index(content, delimiter, index)) + 1), delimiter, '');