[Docs] add `initCap` examples
61 KiB
slug | sidebar_position | sidebar_label |
---|---|---|
/en/sql-reference/functions/string-functions | 170 | Strings |
import VersionBadge from '@theme/badges/VersionBadge';
Functions for Working with Strings
Functions for searching in strings and for replacing in strings are described separately.
empty
Checks whether the input string is empty. A string is considered non-empty if it contains at least one byte, even if this byte is a space or the null byte.
The function is also available for arrays and UUIDs.
Syntax
empty(x)
Arguments
x
— Input value. String.
Returned value
- Returns
1
for an empty string or0
for a non-empty string. UInt8.
Example
SELECT empty('');
Result:
┌─empty('')─┐
│ 1 │
└───────────┘
notEmpty
Checks whether the input string is non-empty. A string is considered non-empty if it contains at least one byte, even if this byte is a space or the null byte.
The function is also available for arrays and UUIDs.
Syntax
notEmpty(x)
Arguments
x
— Input value. String.
Returned value
- Returns
1
for a non-empty string or0
for an empty string string. UInt8.
Example
SELECT notEmpty('text');
Result:
┌─notEmpty('text')─┐
│ 1 │
└──────────────────┘
length
Returns the length of a string in bytes rather than in characters or Unicode code points. The function also works for arrays.
Alias: OCTET_LENGTH
Syntax
length(s)
Parameters
Returned value
- Length of the string or array
s
in bytes. UInt64.
Example
Query:
SELECT length('Hello, world!');
Result:
┌─length('Hello, world!')─┐
│ 13 │
└─────────────────────────┘
Query:
SELECT length([1, 2, 3, 4]);
Result:
┌─length([1, 2, 3, 4])─┐
│ 4 │
└──────────────────────┘
lengthUTF8
Returns the length of a string in Unicode code points rather than in bytes or characters. It assumes that the string contains valid UTF-8 encoded text. If this assumption is violated, no exception is thrown and the result is undefined.
Aliases:
CHAR_LENGTH
CHARACTER_LENGTH
Syntax
lengthUTF8(s)
Parameters
s
— String containing valid UTF-8 encoded text. String.
Returned value
- Length of the string
s
in Unicode code points. UInt64.
Example
Query:
SELECT lengthUTF8('Здравствуй, мир!');
Result:
┌─lengthUTF8('Здравствуй, мир!')─┐
│ 16 │
└────────────────────────────────┘
left
Returns a substring of string s
with a specified offset
starting from the left.
Syntax
left(s, offset)
Parameters
s
— The string to calculate a substring from. String or FixedString.offset
— The number of bytes of the offset. UInt*.
Returned value
- For positive
offset
: A substring ofs
withoffset
many bytes, starting from the left of the string. - For negative
offset
: A substring ofs
withlength(s) - |offset|
bytes, starting from the left of the string. - An empty string if
length
is 0.
Example
Query:
SELECT left('Hello', 3);
Result:
Hel
Query:
SELECT left('Hello', -3);
Result:
He
leftUTF8
Returns a substring of a UTF-8 encoded string s
with a specified offset
starting from the left.
Syntax
leftUTF8(s, offset)
Parameters
s
— The UTF-8 encoded string to calculate a substring from. String or FixedString.offset
— The number of bytes of the offset. UInt*.
Returned value
- For positive
offset
: A substring ofs
withoffset
many bytes, starting from the left of the string. - For negative
offset
: A substring ofs
withlength(s) - |offset|
bytes, starting from the left of the string. - An empty string if
length
is 0.
Example
Query:
SELECT leftUTF8('Привет', 4);
Result:
Прив
Query:
SELECT leftUTF8('Привет', -4);
Result:
Пр
leftPad
Pads a string from the left with spaces or with a specified string (multiple times, if needed) until the resulting string reaches the specified length
.
Syntax
leftPad(string, length[, pad_string])
Alias: LPAD
Arguments
string
— Input string that should be padded. String.length
— The length of the resulting string. UInt or Int. If the value is smaller than the input string length, then the input string is shortened tolength
characters.pad_string
— The string to pad the input string with. String. Optional. If not specified, then the input string is padded with spaces.
Returned value
- A left-padded string of the given length. String.
Example
SELECT leftPad('abc', 7, '*'), leftPad('def', 7);
Result:
┌─leftPad('abc', 7, '*')─┬─leftPad('def', 7)─┐
│ ****abc │ def │
└────────────────────────┴───────────────────┘
leftPadUTF8
Pads the string from the left with spaces or a specified string (multiple times, if needed) until the resulting string reaches the given length. Unlike leftPad which measures the string length in bytes, the string length is measured in code points.
Syntax
leftPadUTF8(string, length[, pad_string])
Arguments
string
— Input string that should be padded. String.length
— The length of the resulting string. UInt or Int. If the value is smaller than the input string length, then the input string is shortened tolength
characters.pad_string
— The string to pad the input string with. String. Optional. If not specified, then the input string is padded with spaces.
Returned value
- A left-padded string of the given length. String.
Example
SELECT leftPadUTF8('абвг', 7, '*'), leftPadUTF8('дежз', 7);
Result:
┌─leftPadUTF8('абвг', 7, '*')─┬─leftPadUTF8('дежз', 7)─┐
│ ***абвг │ дежз │
└─────────────────────────────┴────────────────────────┘
right
Returns a substring of string s
with a specified offset
starting from the right.
Syntax
right(s, offset)
Parameters
s
— The string to calculate a substring from. String or FixedString.offset
— The number of bytes of the offset. UInt*.
Returned value
- For positive
offset
: A substring ofs
withoffset
many bytes, starting from the right of the string. - For negative
offset
: A substring ofs
withlength(s) - |offset|
bytes, starting from the right of the string. - An empty string if
length
is 0.
Example
Query:
SELECT right('Hello', 3);
Result:
llo
Query:
SELECT right('Hello', -3);
Result:
lo
rightUTF8
Returns a substring of UTF-8 encoded string s
with a specified offset
starting from the right.
Syntax
rightUTF8(s, offset)
Parameters
s
— The UTF-8 encoded string to calculate a substring from. String or FixedString.offset
— The number of bytes of the offset. UInt*.
Returned value
- For positive
offset
: A substring ofs
withoffset
many bytes, starting from the right of the string. - For negative
offset
: A substring ofs
withlength(s) - |offset|
bytes, starting from the right of the string. - An empty string if
length
is 0.
Example
Query:
SELECT rightUTF8('Привет', 4);
Result:
ивет
Query:
SELECT rightUTF8('Привет', -4);
Result:
ет
rightPad
Pads a string from the right with spaces or with a specified string (multiple times, if needed) until the resulting string reaches the specified length
.
Syntax
rightPad(string, length[, pad_string])
Alias: RPAD
Arguments
string
— Input string that should be padded. String.length
— The length of the resulting string. UInt or Int. If the value is smaller than the input string length, then the input string is shortened tolength
characters.pad_string
— The string to pad the input string with. String. Optional. If not specified, then the input string is padded with spaces.
Returned value
- A left-padded string of the given length. String.
Example
SELECT rightPad('abc', 7, '*'), rightPad('abc', 7);
Result:
┌─rightPad('abc', 7, '*')─┬─rightPad('abc', 7)─┐
│ abc**** │ abc │
└─────────────────────────┴────────────────────┘
rightPadUTF8
Pads the string from the right with spaces or a specified string (multiple times, if needed) until the resulting string reaches the given length. Unlike rightPad which measures the string length in bytes, the string length is measured in code points.
Syntax
rightPadUTF8(string, length[, pad_string])
Arguments
string
— Input string that should be padded. String.length
— The length of the resulting string. UInt or Int. If the value is smaller than the input string length, then the input string is shortened tolength
characters.pad_string
— The string to pad the input string with. String. Optional. If not specified, then the input string is padded with spaces.
Returned value
- A right-padded string of the given length. String.
Example
SELECT rightPadUTF8('абвг', 7, '*'), rightPadUTF8('абвг', 7);
Result:
┌─rightPadUTF8('абвг', 7, '*')─┬─rightPadUTF8('абвг', 7)─┐
│ абвг*** │ абвг │
└──────────────────────────────┴─────────────────────────┘
lower
Converts the ASCII Latin symbols in a string to lowercase.
Syntax*
lower(input)
Alias: lcase
Parameters
input
: A string type String.
Returned value
- A String data type value.
Example
Query:
SELECT lower('CLICKHOUSE');
┌─lower('CLICKHOUSE')─┐
│ clickhouse │
└─────────────────────┘
upper
Converts the ASCII Latin symbols in a string to uppercase.
Syntax
upper(input)
Alias: ucase
Parameters
input
— A string type String.
Returned value
- A String data type value.
Examples
Query:
SELECT upper('clickhouse');
┌─upper('clickhouse')─┐
│ CLICKHOUSE │
└─────────────────────┘
lowerUTF8
Converts a string to lowercase, assuming that the string contains valid UTF-8 encoded text. If this assumption is violated, no exception is thrown and the result is undefined.
:::note
Does not detect the language, e.g. for Turkish the result might not be exactly correct (i/İ vs. i/I). If the length of the UTF-8 byte sequence is different for upper and lower case of a code point (such as ẞ
and ß
), the result may be incorrect for this code point.
:::
Syntax
lowerUTF8(input)
Parameters
input
— A string type String.
Returned value
- A String data type value.
Example
Query:
SELECT lowerUTF8('MÜNCHEN') as Lowerutf8;
Result:
┌─Lowerutf8─┐
│ münchen │
└───────────┘
upperUTF8
Converts a string to uppercase, assuming that the string contains valid UTF-8 encoded text. If this assumption is violated, no exception is thrown and the result is undefined.
:::note
Does not detect the language, e.g. for Turkish the result might not be exactly correct (i/İ vs. i/I). If the length of the UTF-8 byte sequence is different for upper and lower case of a code point (such as ẞ
and ß
), the result may be incorrect for this code point.
:::
Syntax
upperUTF8(input)
Parameters
input
— A string type String.
Returned value
- A String data type value.
Example
Query:
SELECT upperUTF8('München') as Upperutf8;
Result:
┌─Upperutf8─┐
│ MÜNCHEN │
└───────────┘
isValidUTF8
Returns 1, if the set of bytes constitutes valid UTF-8-encoded text, otherwise 0.
Syntax
isValidUTF8(input)
Parameters
input
— A string type String.
Returned value
- Returns
1
, if the set of bytes constitutes valid UTF-8-encoded text, otherwise0
.
Query:
SELECT isValidUTF8('\xc3\xb1') AS valid, isValidUTF8('\xc3\x28') AS invalid;
Result:
┌─valid─┬─invalid─┐
│ 1 │ 0 │
└───────┴─────────┘
toValidUTF8
Replaces invalid UTF-8 characters by the <EFBFBD>
(U+FFFD) character. All running in a row invalid characters are collapsed into the one replacement character.
Syntax
toValidUTF8(input_string)
Arguments
input_string
— Any set of bytes represented as the String data type object.
Returned value
- A valid UTF-8 string.
Example
SELECT toValidUTF8('\x61\xF0\x80\x80\x80b');
┌─toValidUTF8('a<><61><EFBFBD><EFBFBD>b')─┐
│ a<>b │
└───────────────────────┘
repeat
Concatenates a string as many times with itself as specified.
Syntax
repeat(s, n)
Alias: REPEAT
Arguments
s
— The string to repeat. String.n
— The number of times to repeat the string. UInt* or Int*.
Returned value
A string containing string s
repeated n
times. If n
<= 0, the function returns the empty string. String.
Example
SELECT repeat('abc', 10);
Result:
┌─repeat('abc', 10)──────────────┐
│ abcabcabcabcabcabcabcabcabcabc │
└────────────────────────────────┘
space
Concatenates a space (
) as many times with itself as specified.
Syntax
space(n)
Alias: SPACE
.
Arguments
n
— The number of times to repeat the space. UInt* or Int*.
Returned value
The string containing string
repeated n
times. If n
<= 0, the function returns the empty string. String.
Example
Query:
SELECT space(3);
Result:
┌─space(3) ────┐
│ │
└──────────────┘
reverse
Reverses the sequence of bytes in a string.
reverseUTF8
Reverses a sequence of Unicode code points in a string. Assumes that the string contains valid UTF-8 encoded text. If this assumption is violated, no exception is thrown and the result is undefined.
concat
Concatenates the given arguments.
Syntax
concat(s1, s2, ...)
Arguments
Values of arbitrary type.
Arguments which are not of types String or FixedString are converted to strings using their default serialization. As this decreases performance, it is not recommended to use non-String/FixedString arguments.
Returned values
The String created by concatenating the arguments.
If any of arguments is NULL
, the function returns NULL
.
Example
Query:
SELECT concat('Hello, ', 'World!');
Result:
┌─concat('Hello, ', 'World!')─┐
│ Hello, World! │
└─────────────────────────────┘
Query:
SELECT concat(42, 144);
Result:
┌─concat(42, 144)─┐
│ 42144 │
└─────────────────┘
concatAssumeInjective
Like concat but assumes that concat(s1, s2, ...) → sn
is injective. Can be used for optimization of GROUP BY.
A function is called injective if it returns for different arguments different results. In other words: different arguments never produce identical result.
Syntax
concatAssumeInjective(s1, s2, ...)
Arguments
Values of type String or FixedString.
Returned values
The String created by concatenating the arguments.
If any of argument values is NULL
, the function returns NULL
.
Example
Input table:
CREATE TABLE key_val(`key1` String, `key2` String, `value` UInt32) ENGINE = TinyLog;
INSERT INTO key_val VALUES ('Hello, ','World',1), ('Hello, ','World',2), ('Hello, ','World!',3), ('Hello',', World!',2);
SELECT * from key_val;
┌─key1────┬─key2─────┬─value─┐
│ Hello, │ World │ 1 │
│ Hello, │ World │ 2 │
│ Hello, │ World! │ 3 │
│ Hello │ , World! │ 2 │
└─────────┴──────────┴───────┘
SELECT concat(key1, key2), sum(value) FROM key_val GROUP BY concatAssumeInjective(key1, key2);
Result:
┌─concat(key1, key2)─┬─sum(value)─┐
│ Hello, World! │ 3 │
│ Hello, World! │ 2 │
│ Hello, World │ 3 │
└────────────────────┴────────────┘
concatWithSeparator
Concatenates the given strings with a given separator.
Syntax
concatWithSeparator(sep, expr1, expr2, expr3...)
Alias: concat_ws
Arguments
- sep — separator. Const String or FixedString.
- exprN — expression to be concatenated. Arguments which are not of types String or FixedString are converted to strings using their default serialization. As this decreases performance, it is not recommended to use non-String/FixedString arguments.
Returned values
The String created by concatenating the arguments.
If any of the argument values is NULL
, the function returns NULL
.
Example
SELECT concatWithSeparator('a', '1', '2', '3', '4')
Result:
┌─concatWithSeparator('a', '1', '2', '3', '4')─┐
│ 1a2a3a4 │
└──────────────────────────────────────────────┘
concatWithSeparatorAssumeInjective
Like concatWithSeparator
but assumes that concatWithSeparator(sep, expr1, expr2, expr3...) → result
is injective. Can be used for optimization of GROUP BY.
A function is called injective if it returns for different arguments different results. In other words: different arguments never produce identical result.
substring
Returns the substring of a string s
which starts at the specified byte index offset
. Byte counting starts from 1. If offset
is 0, an empty string is returned. If offset
is negative, the substring starts pos
characters from the end of the string, rather than from the beginning. An optional argument length
specifies the maximum number of bytes the returned substring may have.
Syntax
substring(s, offset[, length])
Aliases:
substr
mid
byteSlice
Arguments
s
— The string to calculate a substring from. String, FixedString or Enumoffset
— The starting position of the substring ins
. (U)Int*.length
— The maximum length of the substring. (U)Int*. Optional.
Returned value
A substring of s
with length
many bytes, starting at index offset
. String.
Example
SELECT 'database' AS db, substr(db, 5), substr(db, 5, 1)
Result:
┌─db───────┬─substring('database', 5)─┬─substring('database', 5, 1)─┐
│ database │ base │ b │
└──────────┴──────────────────────────┴─────────────────────────────┘
substringUTF8
Returns the substring of a string s
which starts at the specified byte index offset
for Unicode code points. Byte counting starts from 1
. If offset
is 0
, an empty string is returned. If offset
is negative, the substring starts pos
characters from the end of the string, rather than from the beginning. An optional argument length
specifies the maximum number of bytes the returned substring may have.
Assumes that the string contains valid UTF-8 encoded text. If this assumption is violated, no exception is thrown and the result is undefined.
Syntax
substringUTF8(s, offset[, length])
Arguments
s
— The string to calculate a substring from. String, FixedString or Enumoffset
— The starting position of the substring ins
. (U)Int*.length
— The maximum length of the substring. (U)Int*. Optional.
Returned value
A substring of s
with length
many bytes, starting at index offset
.
Implementation details
Assumes that the string contains valid UTF-8 encoded text. If this assumption is violated, no exception is thrown and the result is undefined.
Example
SELECT 'Täglich grüßt das Murmeltier.' AS str,
substringUTF8(str, 9),
substringUTF8(str, 9, 5)
Täglich grüßt das Murmeltier. grüßt das Murmeltier. grüßt
substringIndex
Returns the substring of s
before count
occurrences of the delimiter delim
, as in Spark or MySQL.
Syntax
substringIndex(s, delim, count)
Alias: SUBSTRING_INDEX
Arguments
- s — The string to extract substring from. String.
- delim — The character to split. String.
- count — The number of occurrences of the delimiter to count before extracting the substring. If count is positive, everything to the left of the final delimiter (counting from the left) is returned. If count is negative, everything to the right of the final delimiter (counting from the right) is returned. UInt or Int
Example
SELECT substringIndex('www.clickhouse.com', '.', 2)
Result:
┌─substringIndex('www.clickhouse.com', '.', 2)─┐
│ www.clickhouse │
└──────────────────────────────────────────────┘
substringIndexUTF8
Returns the substring of s
before count
occurrences of the delimiter delim
, specifically for Unicode code points.
Assumes that the string contains valid UTF-8 encoded text. If this assumption is violated, no exception is thrown and the result is undefined.
Syntax
substringIndexUTF8(s, delim, count)
Arguments
s
— The string to extract substring from. String.delim
— The character to split. String.count
— The number of occurrences of the delimiter to count before extracting the substring. If count is positive, everything to the left of the final delimiter (counting from the left) is returned. If count is negative, everything to the right of the final delimiter (counting from the right) is returned. UInt or Int
Returned value
A substring String of s
before count
occurrences of delim
.
Implementation details
Assumes that the string contains valid UTF-8 encoded text. If this assumption is violated, no exception is thrown and the result is undefined.
Example
SELECT substringIndexUTF8('www.straßen-in-europa.de', '.', 2)
www.straßen-in-europa
appendTrailingCharIfAbsent
Appends character c
to string s
if s
is non-empty and does not end with character c
.
Syntax
appendTrailingCharIfAbsent(s, c)
convertCharset
Returns string s
converted from the encoding from
to encoding to
.
Syntax
convertCharset(s, from, to)
base58Encode
Encodes a String using Base58 in the "Bitcoin" alphabet.
Syntax
base58Encode(plaintext)
Arguments
plaintext
— String column or constant.
Returned value
- A string containing the encoded value of the argument. String.
Example
SELECT base58Encode('Encoded');
Result:
┌─base58Encode('Encoded')─┐
│ 3dc8KtHrwM │
└─────────────────────────┘
base58Decode
Accepts a String and decodes it using Base58 encoding scheme using "Bitcoin" alphabet.
Syntax
base58Decode(encoded)
Arguments
encoded
— String column or constant. If the string is not a valid Base58-encoded value, an exception is thrown.
Returned value
- A string containing the decoded value of the argument. String.
Example
SELECT base58Decode('3dc8KtHrwM');
Result:
┌─base58Decode('3dc8KtHrwM')─┐
│ Encoded │
└────────────────────────────┘
tryBase58Decode
Like base58Decode
but returns an empty string in case of error.
Syntax
tryBase58Decode(encoded)
Parameters
encoded
: String column or constant. If the string is not a valid Base58-encoded value, returns an empty string in case of error.
Returned value
- A string containing the decoded value of the argument.
Examples
Query:
SELECT tryBase58Decode('3dc8KtHrwM') as res, tryBase58Decode('invalid') as res_invalid;
┌─res─────┬─res_invalid─┐
│ Encoded │ │
└─────────┴─────────────┘
base64Encode
Encodes a String or FixedString as base64, according to RFC 4648.
Alias: TO_BASE64
.
Syntax
base64Encode(plaintext)
Arguments
plaintext
— String column or constant.
Returned value
- A string containing the encoded value of the argument.
Example
SELECT base64Encode('clickhouse');
Result:
┌─base64Encode('clickhouse')─┐
│ Y2xpY2tob3VzZQ== │
└────────────────────────────┘
base64URLEncode
Encodes an URL (String or FixedString) as base64 with URL-specific modifications, according to RFC 4648.
Syntax
base64URLEncode(url)
Arguments
url
— String column or constant.
Returned value
- A string containing the encoded value of the argument.
Example
SELECT base64URLEncode('https://clickhouse.com');
Result:
┌─base64URLEncode('https://clickhouse.com')─┐
│ aHR0cDovL2NsaWNraG91c2UuY29t │
└───────────────────────────────────────────┘
base64Decode
Accepts a String and decodes it from base64, according to RFC 4648. Throws an exception in case of an error.
Alias: FROM_BASE64
.
Syntax
base64Decode(encoded)
Arguments
encoded
— String column or constant. If the string is not a valid Base64-encoded value, an exception is thrown.
Returned value
- A string containing the decoded value of the argument.
Example
SELECT base64Decode('Y2xpY2tob3VzZQ==');
Result:
┌─base64Decode('Y2xpY2tob3VzZQ==')─┐
│ clickhouse │
└──────────────────────────────────┘
base64URLDecode
Accepts a base64-encoded URL and decodes it from base64 with URL-specific modifications, according to RFC 4648. Throws an exception in case of an error.
Syntax
base64URLDecode(encodedUrl)
Arguments
encodedURL
— String column or constant. If the string is not a valid Base64-encoded value with URL-specific modifications, an exception is thrown.
Returned value
- A string containing the decoded value of the argument.
Example
SELECT base64URLDecode('aHR0cDovL2NsaWNraG91c2UuY29t');
Result:
┌─base64URLDecode('aHR0cDovL2NsaWNraG91c2UuY29t')─┐
│ https://clickhouse.com │
└─────────────────────────────────────────────────┘
tryBase64Decode
Like base64Decode
but returns an empty string in case of error.
Syntax
tryBase64Decode(encoded)
Arguments
encoded
— String column or constant. If the string is not a valid Base64-encoded value, returns an empty string.
Returned value
- A string containing the decoded value of the argument.
Examples
Query:
SELECT tryBase64Decode('RW5jb2RlZA==') as res, tryBase64Decode('invalid') as res_invalid;
┌─res────────┬─res_invalid─┐
│ clickhouse │ │
└────────────┴─────────────┘
tryBase64URLDecode
Like base64URLDecode
but returns an empty string in case of error.
Syntax
tryBase64URLDecode(encodedUrl)
Parameters
encodedURL
— String column or constant. If the string is not a valid Base64-encoded value with URL-specific modifications, returns an empty string.
Returned value
- A string containing the decoded value of the argument.
Examples
Query:
SELECT tryBase64URLDecode('aHR0cDovL2NsaWNraG91c2UuY29t') as res, tryBase64Decode('aHR0cHM6Ly9jbGlja') as res_invalid;
┌─res────────────────────┬─res_invalid─┐
│ https://clickhouse.com │ │
└────────────────────────┴─────────────┘
endsWith
Returns whether string str
ends with suffix
.
Syntax
endsWith(str, suffix)
endsWithUTF8
Returns whether string str
ends with suffix
, the difference between endsWithUTF8
and endsWith
is that endsWithUTF8
match str
and suffix
by UTF-8 characters.
Syntax
endsWithUTF8(str, suffix)
Example
SELECT endsWithUTF8('中国', '\xbd'), endsWith('中国', '\xbd')
Result:
┌─endsWithUTF8('中国', '½')─┬─endsWith('中国', '½')─┐
│ 0 │ 1 │
└──────────────────────────┴──────────────────────┘
startsWith
Returns whether string str
starts with prefix
.
Syntax
startsWith(str, prefix)
Example
SELECT startsWith('Spider-Man', 'Spi');
startsWithUTF8
Returns whether string str
starts with prefix
, the difference between startsWithUTF8
and startsWith
is that startsWithUTF8
match str
and suffix
by UTF-8 characters.
Example
SELECT startsWithUTF8('中国', '\xe4'), startsWith('中国', '\xe4')
Result:
┌─startsWithUTF8('中国', '⥩─┬─startsWith('中国', '⥩─┐
│ 0 │ 1 │
└────────────────────────────┴────────────────────────┘
trim
Removes the specified characters from the start or end of a string. If not specified otherwise, the function removes whitespace (ASCII-character 32).
Syntax
trim([[LEADING|TRAILING|BOTH] trim_character FROM] input_string)
Arguments
Returned value
A string without leading and/or trailing specified characters. String.
Example
SELECT trim(BOTH ' ()' FROM '( Hello, world! )');
Result:
┌─trim(BOTH ' ()' FROM '( Hello, world! )')─┐
│ Hello, world! │
└───────────────────────────────────────────────┘
trimLeft
Removes the consecutive occurrences of whitespace (ASCII-character 32) from the start of a string.
Syntax
trimLeft(input_string)
Alias: ltrim(input_string)
.
Arguments
input_string
— string to trim. String.
Returned value
A string without leading common whitespaces. String.
Example
SELECT trimLeft(' Hello, world! ');
Result:
┌─trimLeft(' Hello, world! ')─┐
│ Hello, world! │
└─────────────────────────────────────┘
trimRight
Removes the consecutive occurrences of whitespace (ASCII-character 32) from the end of a string.
Syntax
trimRight(input_string)
Alias: rtrim(input_string)
.
Arguments
input_string
— string to trim. String.
Returned value
A string without trailing common whitespaces. String.
Example
SELECT trimRight(' Hello, world! ');
Result:
┌─trimRight(' Hello, world! ')─┐
│ Hello, world! │
└──────────────────────────────────────┘
trimBoth
Removes the consecutive occurrences of whitespace (ASCII-character 32) from both ends of a string.
Syntax
trimBoth(input_string)
Alias: trim(input_string)
.
Arguments
input_string
— string to trim. String.
Returned value
A string without leading and trailing common whitespaces. String.
Example
SELECT trimBoth(' Hello, world! ');
Result:
┌─trimBoth(' Hello, world! ')─┐
│ Hello, world! │
└─────────────────────────────────────┘
CRC32
Returns the CRC32 checksum of a string using CRC-32-IEEE 802.3 polynomial and initial value 0xffffffff
(zlib implementation).
The result type is UInt32.
CRC32IEEE
Returns the CRC32 checksum of a string, using CRC-32-IEEE 802.3 polynomial.
The result type is UInt32.
CRC64
Returns the CRC64 checksum of a string, using CRC-64-ECMA polynomial.
The result type is UInt64.
normalizeQuery
Replaces literals, sequences of literals and complex aliases (containing whitespace, more than two digits or at least 36 bytes long such as UUIDs) with placeholder ?
.
Syntax
normalizeQuery(x)
Arguments
x
— Sequence of characters. String.
Returned value
- Sequence of characters with placeholders. String.
Example
Query:
SELECT normalizeQuery('[1, 2, 3, x]') AS query;
Result:
┌─query────┐
│ [?.., x] │
└──────────┘
normalizeQueryKeepNames
Replaces literals, sequences of literals with placeholder ?
but does not replace complex aliases (containing whitespace, more than two digits
or at least 36 bytes long such as UUIDs). This helps better analyze complex query logs.
Syntax
normalizeQueryKeepNames(x)
Arguments
x
— Sequence of characters. String.
Returned value
- Sequence of characters with placeholders. String.
Example
Query:
SELECT normalizeQuery('SELECT 1 AS aComplexName123'), normalizeQueryKeepNames('SELECT 1 AS aComplexName123');
Result:
┌─normalizeQuery('SELECT 1 AS aComplexName123')─┬─normalizeQueryKeepNames('SELECT 1 AS aComplexName123')─┐
│ SELECT ? AS `?` │ SELECT ? AS aComplexName123 │
└───────────────────────────────────────────────┴────────────────────────────────────────────────────────┘
normalizedQueryHash
Returns identical 64bit hash values without the values of literals for similar queries. Can be helpful to analyze query logs.
Syntax
normalizedQueryHash(x)
Arguments
x
— Sequence of characters. String.
Returned value
- Hash value. UInt64.
Example
Query:
SELECT normalizedQueryHash('SELECT 1 AS `xyz`') != normalizedQueryHash('SELECT 1 AS `abc`') AS res;
Result:
┌─res─┐
│ 1 │
└─────┘
normalizedQueryHashKeepNames
Like normalizedQueryHash it returns identical 64bit hash values without the values of literals for similar queries but it does not replace complex aliases (containing whitespace, more than two digits or at least 36 bytes long such as UUIDs) with a placeholder before hashing. Can be helpful to analyze query logs.
Syntax
normalizedQueryHashKeepNames(x)
Arguments
x
— Sequence of characters. String.
Returned value
- Hash value. UInt64.
Example
SELECT normalizedQueryHash('SELECT 1 AS `xyz123`') != normalizedQueryHash('SELECT 1 AS `abc123`') AS normalizedQueryHash;
SELECT normalizedQueryHashKeepNames('SELECT 1 AS `xyz123`') != normalizedQueryHashKeepNames('SELECT 1 AS `abc123`') AS normalizedQueryHashKeepNames;
Result:
┌─normalizedQueryHash─┐
│ 0 │
└─────────────────────┘
┌─normalizedQueryHashKeepNames─┐
│ 1 │
└──────────────────────────────┘
normalizeUTF8NFC
Converts a string to NFC normalized form, assuming the string is valid UTF8-encoded text.
Syntax
normalizeUTF8NFC(words)
Arguments
words
— UTF8-encoded input string. String.
Returned value
- String transformed to NFC normalization form. String.
Example
SELECT length('â'), normalizeUTF8NFC('â') AS nfc, length(nfc) AS nfc_len;
Result:
┌─length('â')─┬─nfc─┬─nfc_len─┐
│ 2 │ â │ 2 │
└─────────────┴─────┴─────────┘
normalizeUTF8NFD
Converts a string to NFD normalized form, assuming the string is valid UTF8-encoded text.
Syntax
normalizeUTF8NFD(words)
Arguments
words
— UTF8-encoded input string. String.
Returned value
- String transformed to NFD normalization form. String.
Example
SELECT length('â'), normalizeUTF8NFD('â') AS nfd, length(nfd) AS nfd_len;
Result:
┌─length('â')─┬─nfd─┬─nfd_len─┐
│ 2 │ â │ 3 │
└─────────────┴─────┴─────────┘
normalizeUTF8NFKC
Converts a string to NFKC normalized form, assuming the string is valid UTF8-encoded text.
Syntax
normalizeUTF8NFKC(words)
Arguments
words
— UTF8-encoded input string. String.
Returned value
- String transformed to NFKC normalization form. String.
Example
SELECT length('â'), normalizeUTF8NFKC('â') AS nfkc, length(nfkc) AS nfkc_len;
Result:
┌─length('â')─┬─nfkc─┬─nfkc_len─┐
│ 2 │ â │ 2 │
└─────────────┴──────┴──────────┘
normalizeUTF8NFKD
Converts a string to NFKD normalized form, assuming the string is valid UTF8-encoded text.
Syntax
normalizeUTF8NFKD(words)
Arguments
words
— UTF8-encoded input string. String.
Returned value
- String transformed to NFKD normalization form. String.
Example
SELECT length('â'), normalizeUTF8NFKD('â') AS nfkd, length(nfkd) AS nfkd_len;
Result:
┌─length('â')─┬─nfkd─┬─nfkd_len─┐
│ 2 │ â │ 3 │
└─────────────┴──────┴──────────┘
encodeXMLComponent
Escapes characters with special meaning in XML such that they can afterwards be place into a XML text node or attribute.
The following characters are replaced: <
, &
, >
, "
, '
.
Also see the list of XML and HTML character entity references.
Syntax
encodeXMLComponent(x)
Arguments
x
— An input string. String.
Returned value
- The escaped string. String.
Example
SELECT encodeXMLComponent('Hello, "world"!');
SELECT encodeXMLComponent('<123>');
SELECT encodeXMLComponent('&clickhouse');
SELECT encodeXMLComponent('\'foo\'');
Result:
Hello, "world"!
<123>
&clickhouse
'foo'
decodeXMLComponent
Un-escapes substrings with special meaning in XML. These substrings are: "
&
'
>
<
This function also replaces numeric character references with Unicode characters. Both decimal (like ✓
) and hexadecimal (✓
) forms are supported.
Syntax
decodeXMLComponent(x)
Arguments
x
— An input string. String.
Returned value
- The un-escaped string. String.
Example
SELECT decodeXMLComponent(''foo'');
SELECT decodeXMLComponent('< Σ >');
Result:
'foo'
< Σ >
decodeHTMLComponent
Un-escapes substrings with special meaning in HTML. For example: ℏ
>
♦
♥
<
etc.
This function also replaces numeric character references with Unicode characters. Both decimal (like ✓
) and hexadecimal (✓
) forms are supported.
Syntax
decodeHTMLComponent(x)
Arguments
x
— An input string. String.
Returned value
- The un-escaped string. String.
Example
SELECT decodeHTMLComponent(''CH');
SELECT decodeHTMLComponent('I♥ClickHouse');
Result:
'CH'
I♥ClickHouse'
extractTextFromHTML
This function extracts plain text from HTML or XHTML.
It does not conform 100% to the HTML, XML or XHTML specification but the implementation is reasonably accurate and fast. The rules are the following:
- Comments are skipped. Example:
<!-- test -->
. Comment must end with-->
. Nested comments are disallowed. Note: constructions like<!-->
and<!--->
are not valid comments in HTML but they are skipped by other rules. - CDATA is pasted verbatim. Note: CDATA is XML/XHTML-specific and processed on a "best-effort" basis.
script
andstyle
elements are removed with all their content. Note: it is assumed that closing tag cannot appear inside content. For example, in JS string literal has to be escaped like"<\/script>"
. Note: comments and CDATA are possible insidescript
orstyle
- then closing tags are not searched inside CDATA. Example:<script><![CDATA[</script>]]></script>
. But they are still searched inside comments. Sometimes it becomes complicated:<script>var x = "<!--"; </script> var y = "-->"; alert(x + y);</script>
Note:script
andstyle
can be the names of XML namespaces - then they are not treated like usualscript
orstyle
elements. Example:<script:a>Hello</script:a>
. Note: whitespaces are possible after closing tag name:</script >
but not before:< / script>
.- Other tags or tag-like elements are skipped without inner content. Example:
<a>.</a>
Note: it is expected that this HTML is illegal:<a test=">"></a>
Note: it also skips something like tags:<>
,<!>
, etc. Note: tag without end is skipped to the end of input:<hello
- HTML and XML entities are not decoded. They must be processed by separate function.
- Whitespaces in the text are collapsed or inserted by specific rules.
- Whitespaces at the beginning and at the end are removed.
- Consecutive whitespaces are collapsed.
- But if the text is separated by other elements and there is no whitespace, it is inserted.
- It may cause unnatural examples:
Hello<b>world</b>
,Hello<!-- -->world
- there is no whitespace in HTML, but the function inserts it. Also consider:Hello<p>world</p>
,Hello<br>world
. This behavior is reasonable for data analysis, e.g. to convert HTML to a bag of words.
- Also note that correct handling of whitespaces requires the support of
<pre></pre>
and CSSdisplay
andwhite-space
properties.
Syntax
extractTextFromHTML(x)
Arguments
x
— input text. String.
Returned value
- Extracted text. String.
Example
The first example contains several tags and a comment and also shows whitespace processing.
The second example shows CDATA
and script
tag processing.
In the third example text is extracted from the full HTML response received by the url function.
SELECT extractTextFromHTML(' <p> A text <i>with</i><b>tags</b>. <!-- comments --> </p> ');
SELECT extractTextFromHTML('<![CDATA[The content within <b>CDATA</b>]]> <script>alert("Script");</script>');
SELECT extractTextFromHTML(html) FROM url('http://www.donothingfor2minutes.com/', RawBLOB, 'html String');
Result:
A text with tags .
The content within <b>CDATA</b>
Do Nothing for 2 Minutes 2:00
ascii
Returns the ASCII code point (as Int32) of the first character of string s
.
If s
is empty, the result is 0. If the first character is not an ASCII character or not part of the Latin-1 supplement range of UTF-16, the result is undefined.
Syntax
ascii(s)
soundex
Returns the Soundex code of a string.
Syntax
soundex(val)
Arguments
val
— Input value. String
Returned value
- The Soundex code of the input value. String
Example
select soundex('aksel');
Result:
┌─soundex('aksel')─┐
│ A240 │
└──────────────────┘
punycodeEncode
Returns the Punycode representation of a string. The string must be UTF8-encoded, otherwise the behavior is undefined.
Syntax
punycodeEncode(val)
Arguments
val
— Input value. String
Returned value
- A Punycode representation of the input value. String
Example
select punycodeEncode('München');
Result:
┌─punycodeEncode('München')─┐
│ Mnchen-3ya │
└───────────────────────────┘
punycodeDecode
Returns the UTF8-encoded plaintext of a Punycode-encoded string. If no valid Punycode-encoded string is given, an exception is thrown.
Syntax
punycodeEncode(val)
Arguments
val
— Punycode-encoded string. String
Returned value
- The plaintext of the input value. String
Example
select punycodeDecode('Mnchen-3ya');
Result:
┌─punycodeDecode('Mnchen-3ya')─┐
│ München │
└──────────────────────────────┘
tryPunycodeDecode
Like punycodeDecode
but returns an empty string if no valid Punycode-encoded string is given.
idnaEncode
Returns the ASCII representation (ToASCII algorithm) of a domain name according to the Internationalized Domain Names in Applications (IDNA) mechanism. The input string must be UTF-encoded and translatable to an ASCII string, otherwise an exception is thrown. Note: No percent decoding or trimming of tabs, spaces or control characters is performed.
Syntax
idnaEncode(val)
Arguments
val
— Input value. String
Returned value
- A ASCII representation according to the IDNA mechanism of the input value. String
Example
select idnaEncode('straße.münchen.de');
Result:
┌─idnaEncode('straße.münchen.de')─────┐
│ xn--strae-oqa.xn--mnchen-3ya.de │
└─────────────────────────────────────┘
tryIdnaEncode
Like idnaEncode
but returns an empty string in case of an error instead of throwing an exception.
idnaDecode
Returns the Unicode (UTF-8) representation (ToUnicode algorithm) of a domain name according to the Internationalized Domain Names in Applications (IDNA) mechanism.
In case of an error (e.g. because the input is invalid), the input string is returned.
Note that repeated application of idnaEncode()
and idnaDecode()
does not necessarily return the original string due to case normalization.
Syntax
idnaDecode(val)
Arguments
val
— Input value. String
Returned value
- A Unicode (UTF-8) representation according to the IDNA mechanism of the input value. String
Example
select idnaDecode('xn--strae-oqa.xn--mnchen-3ya.de');
Result:
┌─idnaDecode('xn--strae-oqa.xn--mnchen-3ya.de')─┐
│ straße.münchen.de │
└───────────────────────────────────────────────┘
byteHammingDistance
Calculates the hamming distance between two byte strings.
Syntax
byteHammingDistance(string1, string2)
Examples
SELECT byteHammingDistance('karolin', 'kathrin');
Result:
┌─byteHammingDistance('karolin', 'kathrin')─┐
│ 3 │
└───────────────────────────────────────────┘
Alias: mismatches
stringJaccardIndex
Calculates the Jaccard similarity index between two byte strings.
Syntax
stringJaccardIndex(string1, string2)
Examples
SELECT stringJaccardIndex('clickhouse', 'mouse');
Result:
┌─stringJaccardIndex('clickhouse', 'mouse')─┐
│ 0.4 │
└───────────────────────────────────────────┘
stringJaccardIndexUTF8
Like stringJaccardIndex but for UTF8-encoded strings.
editDistance
Calculates the edit distance between two byte strings.
Syntax
editDistance(string1, string2)
Examples
SELECT editDistance('clickhouse', 'mouse');
Result:
┌─editDistance('clickhouse', 'mouse')─┐
│ 6 │
└─────────────────────────────────────┘
Alias: levenshteinDistance
editDistanceUTF8
Calculates the edit distance between two UTF8 strings.
Syntax
editDistanceUTF8(string1, string2)
Examples
SELECT editDistanceUTF8('我是谁', '我是我');
Result:
┌─editDistanceUTF8('我是谁', '我是我')──┐
│ 1 │
└─────────────────────────────────────┘
Alias: levenshteinDistanceUTF8
damerauLevenshteinDistance
Calculates the Damerau-Levenshtein distance between two byte strings.
Syntax
damerauLevenshteinDistance(string1, string2)
Examples
SELECT damerauLevenshteinDistance('clickhouse', 'mouse');
Result:
┌─damerauLevenshteinDistance('clickhouse', 'mouse')─┐
│ 6 │
└───────────────────────────────────────────────────┘
jaroSimilarity
Calculates the Jaro similarity between two byte strings.
Syntax
jaroSimilarity(string1, string2)
Examples
SELECT jaroSimilarity('clickhouse', 'click');
Result:
┌─jaroSimilarity('clickhouse', 'click')─┐
│ 0.8333333333333333 │
└───────────────────────────────────────┘
jaroWinklerSimilarity
Calculates the Jaro-Winkler similarity between two byte strings.
Syntax
jaroWinklerSimilarity(string1, string2)
Examples
SELECT jaroWinklerSimilarity('clickhouse', 'click');
Result:
┌─jaroWinklerSimilarity('clickhouse', 'click')─┐
│ 0.8999999999999999 │
└──────────────────────────────────────────────┘
initcap
Convert the first letter of each word to upper case and the rest to lower case. Words are sequences of alphanumeric characters separated by non-alphanumeric characters.
:::note
Because initCap
converts only the first letter of each word to upper case you may observe unexpected behaviour for words containing apostrophes or capital letters. For example:
SELECT initCap('mother''s daughter'), initCap('joe McAdam');
will return
┌─initCap('mother\'s daughter')─┬─initCap('joe McAdam')─┐
│ Mother'S Daughter │ Joe Mcadam │
└───────────────────────────────┴───────────────────────┘
This is a known behaviour, with no plans currently to fix it. :::
Syntax
initcap(val)
Arguments
val
— Input value. String.
Returned value
val
with the first letter of each word converted to upper case. String.
Example
Query:
SELECT initcap('building for fast');
Result:
┌─initcap('building for fast')─┐
│ Building For Fast │
└──────────────────────────────┘
initcapUTF8
Like initcap, initcapUTF8
converts the first letter of each word to upper case and the rest to lower case. Assumes that the string contains valid UTF-8 encoded text.
If this assumption is violated, no exception is thrown and the result is undefined.
:::note This function does not detect the language, e.g. for Turkish the result might not be exactly correct (i/İ vs. i/I). If the length of the UTF-8 byte sequence is different for upper and lower case of a code point, the result may be incorrect for this code point. :::
Syntax
initcapUTF8(val)
Arguments
val
— Input value. String.
Returned value
val
with the first letter of each word converted to upper case. String.
Example
Query:
SELECT initcapUTF8('не тормозит');
Result:
┌─initcapUTF8('не тормозит')─┐
│ Не Тормозит │
└────────────────────────────┘
firstLine
Returns the first line from a multi-line string.
Syntax
firstLine(val)
Arguments
val
— Input value. String
Returned value
- The first line of the input value or the whole value if there is no line separators. String
Example
select firstLine('foo\nbar\nbaz');
Result:
┌─firstLine('foo\nbar\nbaz')─┐
│ foo │
└────────────────────────────┘