2020-04-03 13:23:32 +00:00
---
2022-08-28 14:53:34 +00:00
slug: /en/sql-reference/functions/string-functions
2023-04-19 17:05:55 +00:00
sidebar_position: 170
2022-04-09 13:29:05 +00:00
sidebar_label: Strings
2020-04-03 13:23:32 +00:00
---
2022-06-02 10:55:18 +00:00
# Functions for Working with Strings
2017-12-28 15:13:23 +00:00
2023-04-20 10:08:49 +00:00
Functions for [searching ](string-search-functions.md ) in strings and for [replacing ](string-replace-functions.md ) in strings are described separately.
2020-06-19 10:09:45 +00:00
2022-06-02 10:55:18 +00:00
## empty
2017-04-03 19:49:50 +00:00
2021-08-03 13:07:46 +00:00
Checks whether the input string is empty.
2023-04-19 20:04:59 +00:00
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 ](array-functions.md#function-empty ) and [UUIDs ](uuid-functions.md#empty ).
2021-08-03 13:07:46 +00:00
**Syntax**
``` sql
empty(x)
```
**Arguments**
2023-04-19 15:55:29 +00:00
- `x` — Input value. [String ](../data-types/string.md ).
2021-08-03 13:07:46 +00:00
**Returned value**
2023-04-19 15:55:29 +00:00
- Returns `1` for an empty string or `0` for a non-empty string.
2021-08-03 13:07:46 +00:00
Type: [UInt8 ](../data-types/int-uint.md ).
**Example**
```sql
SELECT empty('');
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-08-03 13:07:46 +00:00
┌─empty('')─┐
│ 1 │
└───────────┘
```
2017-04-03 19:49:50 +00:00
2022-06-02 10:55:18 +00:00
## notEmpty
2017-12-28 15:13:23 +00:00
2021-08-10 10:53:35 +00:00
Checks whether the input string is non-empty.
2021-08-06 09:04:55 +00:00
2023-04-19 20:04:59 +00:00
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 ](array-functions.md#function-notempty ) and [UUIDs ](uuid-functions.md#notempty ).
2021-08-06 09:04:55 +00:00
**Syntax**
``` sql
2021-08-10 10:53:35 +00:00
notEmpty(x)
2021-08-06 09:04:55 +00:00
```
**Arguments**
2023-04-19 15:55:29 +00:00
- `x` — Input value. [String ](../data-types/string.md ).
2021-08-06 09:04:55 +00:00
**Returned value**
2023-04-19 15:55:29 +00:00
- Returns `1` for a non-empty string or `0` for an empty string string.
2021-08-06 09:04:55 +00:00
Type: [UInt8 ](../data-types/int-uint.md ).
**Example**
```sql
2021-08-10 10:53:35 +00:00
SELECT notEmpty('text');
2021-08-06 09:04:55 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-08-10 10:53:35 +00:00
┌─notEmpty('text')─┐
│ 1 │
└──────────────────┘
2021-08-06 09:04:55 +00:00
```
2017-04-03 19:49:50 +00:00
2022-06-02 10:55:18 +00:00
## length
2017-12-28 15:13:23 +00:00
2023-04-19 20:04:59 +00:00
Returns the length of a string in bytes (not: in characters or Unicode code points).
2017-04-26 19:16:38 +00:00
The function also works for arrays.
2017-04-03 19:49:50 +00:00
2023-07-17 02:52:05 +00:00
Alias: `OCTET_LENGTH`
2022-06-02 10:55:18 +00:00
## lengthUTF8
2017-12-28 15:13:23 +00:00
2023-04-19 20:04:59 +00:00
Returns the length of a string in Unicode code points (not: 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.
2019-01-30 10:39:46 +00:00
2023-04-19 20:04:59 +00:00
Alias:
- `CHAR_LENGTH` `
- `CHARACTER_LENGTH`
2019-01-30 10:39:46 +00:00
2022-06-02 10:55:18 +00:00
## leftPad
2021-08-03 18:58:32 +00:00
2023-04-19 20:04:59 +00:00
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` .
2021-08-03 18:58:32 +00:00
**Syntax**
``` sql
2023-04-19 20:04:59 +00:00
leftPad(string, length[, pad_string])
2021-08-03 18:58:32 +00:00
```
2023-04-19 20:04:59 +00:00
Alias: `LPAD`
2021-08-03 18:58:32 +00:00
**Arguments**
2023-04-19 20:04:59 +00:00
- `string` — Input string that should be padded. [String ](../data-types/string.md ).
- `length` — The length of the resulting string. [UInt or Int ](../data-types/int-uint.md ). If the value is smaller than the input string length, then the input string is shortened to `length` characters.
2023-04-19 15:55:29 +00:00
- `pad_string` — The string to pad the input string with. [String ](../data-types/string.md ). Optional. If not specified, then the input string is padded with spaces.
2021-08-03 18:58:32 +00:00
2021-08-09 14:29:26 +00:00
**Returned value**
2021-08-03 18:58:32 +00:00
2023-04-19 20:04:59 +00:00
- A left-padded string of the given length.
2021-08-03 18:58:32 +00:00
Type: [String ](../data-types/string.md ).
**Example**
``` sql
2021-08-09 13:20:20 +00:00
SELECT leftPad('abc', 7, '*'), leftPad('def', 7);
2021-08-03 18:58:32 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-08-09 13:20:26 +00:00
┌─leftPad('abc', 7, '*')─┬─leftPad('def', 7)─┐
│ ** **abc │ def │
└────────────────────────┴───────────────────┘
2021-08-03 18:58:32 +00:00
```
2022-06-02 10:55:18 +00:00
## leftPadUTF8
2021-08-06 15:03:31 +00:00
2023-04-19 20:04:59 +00:00
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 ](#leftpad ) which measures the string length in bytes, the string length is measured in code points.
2021-08-06 15:03:31 +00:00
**Syntax**
``` sql
2023-04-19 20:04:59 +00:00
leftPadUTF8(string, length[, pad_string])
2021-08-06 15:03:31 +00:00
```
**Arguments**
2023-04-19 20:04:59 +00:00
- `string` — Input string that should be padded. [String ](../data-types/string.md ).
- `length` — The length of the resulting string. [UInt or Int ](../data-types/int-uint.md ). If the value is smaller than the input string length, then the input string is shortened to `length` characters.
2023-04-19 15:55:29 +00:00
- `pad_string` — The string to pad the input string with. [String ](../data-types/string.md ). Optional. If not specified, then the input string is padded with spaces.
2021-08-06 15:03:31 +00:00
2021-08-09 14:29:26 +00:00
**Returned value**
2021-08-06 15:03:31 +00:00
2023-04-19 20:04:59 +00:00
- A left-padded string of the given length.
2021-08-06 15:03:31 +00:00
Type: [String ](../data-types/string.md ).
**Example**
``` sql
2021-08-09 13:21:22 +00:00
SELECT leftPadUTF8('абвг', 7, '*'), leftPadUTF8('дежз', 7);
2021-08-06 15:03:31 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-08-09 13:21:28 +00:00
┌─leftPadUTF8('абвг', 7, '*')─┬─leftPadUTF8('дежз', 7)─┐
│ ** *абвг │ дежз │
└─────────────────────────────┴────────────────────────┘
2021-08-06 15:03:31 +00:00
```
2022-06-02 10:55:18 +00:00
## rightPad
2021-08-03 18:58:32 +00:00
2023-04-19 20:04:59 +00:00
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` .
2021-08-03 18:58:32 +00:00
**Syntax**
``` sql
2023-04-19 20:04:59 +00:00
rightPad(string, length[, pad_string])
2021-08-03 18:58:32 +00:00
```
2023-04-19 20:04:59 +00:00
Alias: `RPAD`
2021-08-03 18:58:32 +00:00
**Arguments**
2023-04-19 20:04:59 +00:00
- `string` — Input string that should be padded. [String ](../data-types/string.md ).
- `length` — The length of the resulting string. [UInt or Int ](../data-types/int-uint.md ). If the value is smaller than the input string length, then the input string is shortened to `length` characters.
2023-04-19 15:55:29 +00:00
- `pad_string` — The string to pad the input string with. [String ](../data-types/string.md ). Optional. If not specified, then the input string is padded with spaces.
2021-08-03 18:58:32 +00:00
2021-08-09 14:29:26 +00:00
**Returned value**
2021-08-03 18:58:32 +00:00
2023-04-19 20:04:59 +00:00
- A left-padded string of the given length.
2021-08-03 18:58:32 +00:00
Type: [String ](../data-types/string.md ).
**Example**
``` sql
2021-08-09 13:43:17 +00:00
SELECT rightPad('abc', 7, '*'), rightPad('abc', 7);
2021-08-03 18:58:32 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-08-09 13:43:17 +00:00
┌─rightPad('abc', 7, '*')─┬─rightPad('abc', 7)─┐
│ abc**** │ abc │
└─────────────────────────┴────────────────────┘
2021-08-03 18:58:32 +00:00
```
2022-06-02 10:55:18 +00:00
## rightPadUTF8
2021-08-06 15:03:31 +00:00
2023-04-19 20:04:59 +00:00
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 ](#rightpad ) which measures the string length in bytes, the string length is measured in code points.
2021-08-06 15:03:31 +00:00
**Syntax**
``` sql
2023-04-19 20:04:59 +00:00
rightPadUTF8(string, length[, pad_string])
2021-08-06 15:03:31 +00:00
```
**Arguments**
2023-04-19 20:04:59 +00:00
- `string` — Input string that should be padded. [String ](../data-types/string.md ).
- `length` — The length of the resulting string. [UInt or Int ](../data-types/int-uint.md ). If the value is smaller than the input string length, then the input string is shortened to `length` characters.
2023-04-19 15:55:29 +00:00
- `pad_string` — The string to pad the input string with. [String ](../data-types/string.md ). Optional. If not specified, then the input string is padded with spaces.
2021-08-06 15:03:31 +00:00
2021-08-09 14:29:26 +00:00
**Returned value**
2021-08-06 15:03:31 +00:00
2023-04-19 20:04:59 +00:00
- A right-padded string of the given length.
2021-08-06 15:03:31 +00:00
Type: [String ](../data-types/string.md ).
**Example**
``` sql
2021-08-09 13:43:17 +00:00
SELECT rightPadUTF8('абвг', 7, '*'), rightPadUTF8('абвг', 7);
2021-08-06 15:03:31 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-08-09 13:43:17 +00:00
┌─rightPadUTF8('абвг', 7, '*')─┬─rightPadUTF8('абвг', 7)─┐
│ абвг*** │ абвг │
└──────────────────────────────┴─────────────────────────┘
2021-08-06 15:03:31 +00:00
```
2023-04-19 20:04:59 +00:00
## lower
Converts the ASCII Latin symbols in a string to lowercase.
2017-12-28 15:13:23 +00:00
2023-04-19 20:04:59 +00:00
Alias: `lcase`
2017-04-03 19:49:50 +00:00
2023-04-19 20:04:59 +00:00
## upper
2017-12-28 15:13:23 +00:00
2023-04-19 20:04:59 +00:00
Converts the ASCII Latin symbols in a string to uppercase.
Alias: `ucase`
2017-04-03 19:49:50 +00:00
2022-06-02 10:55:18 +00:00
## lowerUTF8
2017-12-28 15:13:23 +00:00
2023-04-19 20:04:59 +00:00
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.
Does not detect the language, e.g. for Turkish the result might not be exactly correct (i/İ vs. i/I).
2017-12-28 15:13:23 +00:00
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.
2022-06-02 10:55:18 +00:00
## upperUTF8
2017-04-03 19:49:50 +00:00
2023-04-19 20:04:59 +00:00
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.
Does not detect the language, e.g. for Turkish the result might not be exactly correct (i/İ vs. i/I).
2017-12-28 15:13:23 +00:00
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.
2022-06-02 10:55:18 +00:00
## isValidUTF8
2019-04-07 18:58:13 +00:00
2023-04-19 20:04:59 +00:00
Returns 1, if the set of bytes constitutes valid UTF-8-encoded text, otherwise 0.
2019-04-07 18:58:13 +00:00
2022-06-02 10:55:18 +00:00
## toValidUTF8
2019-05-17 12:55:21 +00:00
2019-05-20 14:41:10 +00:00
Replaces invalid UTF-8 characters by the `<60> ` (U+FFFD) character. All running in a row invalid characters are collapsed into the one replacement character.
2023-04-19 20:04:59 +00:00
**Syntax**
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
toValidUTF8(input_string)
2019-05-20 14:41:10 +00:00
```
2021-02-16 11:21:23 +00:00
**Arguments**
2019-05-20 14:41:10 +00:00
2023-04-19 15:55:29 +00:00
- `input_string` — Any set of bytes represented as the [String ](../../sql-reference/data-types/string.md ) data type object.
2019-05-20 14:41:10 +00:00
2023-04-19 20:04:59 +00:00
**Returned value**
- A valid UTF-8 string.
2019-05-20 14:41:10 +00:00
2020-03-19 15:32:53 +00:00
**Example**
2019-05-20 14:41:10 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT toValidUTF8('\x61\xF0\x80\x80\x80b');
2019-05-20 14:41:10 +00:00
```
2020-03-20 10:10:48 +00:00
2023-04-19 20:04:59 +00:00
```result
2019-05-23 11:37:05 +00:00
┌─toValidUTF8('a<> <61> <EFBFBD> <EFBFBD> b')─┐
│ a<> b │
└───────────────────────┘
2021-10-14 10:15:45 +00:00
```
2022-06-02 10:55:18 +00:00
## repeat
2019-10-24 14:59:00 +00:00
2023-05-04 16:35:18 +00:00
Concatenates a string as many times with itself as specified.
2021-02-16 11:31:24 +00:00
2019-10-24 14:59:00 +00:00
**Syntax**
2020-03-20 10:10:48 +00:00
``` sql
2019-10-24 14:59:00 +00:00
repeat(s, n)
```
2023-04-19 20:04:59 +00:00
Alias: `REPEAT`
2021-02-15 21:22:10 +00:00
**Arguments**
2019-10-24 14:59:00 +00:00
2023-04-19 15:55:29 +00:00
- `s` — The string to repeat. [String ](../../sql-reference/data-types/string.md ).
2023-05-22 06:59:08 +00:00
- `n` — The number of times to repeat the string. [UInt* or Int* ](../../sql-reference/data-types/int-uint.md ).
2019-10-24 14:59:00 +00:00
**Returned value**
2023-05-22 06:59:08 +00:00
A string containing string `s` repeated `n` times. If `n` < = 0, the function returns the empty string.
2019-10-24 14:59:00 +00:00
Type: `String` .
**Example**
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT repeat('abc', 10);
2019-10-24 14:59:00 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2019-10-24 14:59:00 +00:00
┌─repeat('abc', 10)──────────────┐
│ abcabcabcabcabcabcabcabcabcabc │
└────────────────────────────────┘
```
2019-05-21 09:08:43 +00:00
2023-05-22 06:59:08 +00:00
## space
Concatenates a space (` `) as many times with itself as specified.
**Syntax**
``` sql
space(n)
```
Alias: `SPACE` .
**Arguments**
- `n` — The number of times to repeat the space. [UInt* or Int* ](../../sql-reference/data-types/int-uint.md ).
**Returned value**
The string containing string ` ` repeated `n` times. If `n` < = 0, the function returns the empty string.
Type: `String` .
**Example**
Query:
``` sql
SELECT space(3);
```
Result:
``` text
┌─space(3) ────┐
│ │
└──────────────┘
```
2022-06-02 10:55:18 +00:00
## reverse
2017-04-03 19:49:50 +00:00
2023-04-19 20:04:59 +00:00
Reverses the sequence of bytes in a string.
2017-04-03 19:49:50 +00:00
2022-06-02 10:55:18 +00:00
## reverseUTF8
2017-12-28 15:13:23 +00:00
2023-04-19 20:04:59 +00:00
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.
2022-06-02 10:55:18 +00:00
## concat
2017-12-28 15:13:23 +00:00
2023-11-15 15:42:00 +00:00
Concatenates the given arguments.
2017-12-28 15:13:23 +00:00
2020-03-20 10:10:48 +00:00
**Syntax**
2019-01-30 10:39:46 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2019-11-08 19:08:55 +00:00
concat(s1, s2, ...)
```
2021-02-15 21:22:10 +00:00
**Arguments**
2019-11-08 19:08:55 +00:00
2023-11-20 15:22:47 +00:00
At least one value of arbitrary type.
2023-11-15 15:42:00 +00:00
Arguments which are not of types [String ](../../sql-reference/data-types/string.md ) or [FixedString ](../../sql-reference/data-types/fixedstring.md ) are converted to strings using their default serialization. As this decreases performance, it is not recommended to use non-String/FixedString arguments.
2019-11-08 19:08:55 +00:00
**Returned values**
2023-04-19 20:04:59 +00:00
The String created by concatenating the arguments.
2019-11-08 19:08:55 +00:00
2023-04-19 20:04:59 +00:00
If any of arguments is `NULL` , the function returns `NULL` .
2019-11-08 19:08:55 +00:00
**Example**
2023-11-15 15:42:00 +00:00
Query:
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT concat('Hello, ', 'World!');
2019-11-08 19:08:55 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2019-12-26 12:51:48 +00:00
┌─concat('Hello, ', 'World!')─┐
│ Hello, World! │
└─────────────────────────────┘
2019-11-08 19:08:55 +00:00
```
2023-11-15 15:42:00 +00:00
Query:
2023-11-15 13:57:34 +00:00
```sql
SELECT concat(42, 144);
```
Result:
```result
┌─concat(42, 144)─┐
│ 42144 │
└─────────────────┘
```
2022-06-02 10:55:18 +00:00
## concatAssumeInjective
2019-11-08 19:08:55 +00:00
2023-04-19 20:04:59 +00:00
Like [concat ](#concat ) but assumes that `concat(s1, s2, ...) → sn` is injective. Can be used for optimization of GROUP BY.
2019-11-08 19:08:55 +00:00
2023-04-19 20:04:59 +00:00
A function is called injective if it returns for different arguments different results. In other words: different arguments never produce identical result.
2019-11-08 19:08:55 +00:00
2020-03-20 10:10:48 +00:00
**Syntax**
2020-03-19 15:32:53 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2020-03-19 15:32:53 +00:00
concatAssumeInjective(s1, s2, ...)
```
2021-02-15 21:22:10 +00:00
**Arguments**
2020-03-19 15:32:53 +00:00
Values of type String or FixedString.
**Returned values**
2023-04-19 20:04:59 +00:00
The String created by concatenating the arguments.
2020-03-19 15:32:53 +00:00
2023-04-19 20:04:59 +00:00
If any of argument values is `NULL` , the function returns `NULL` .
2020-03-19 15:32:53 +00:00
2019-11-08 19:08:55 +00:00
**Example**
2019-12-26 12:51:48 +00:00
Input table:
2020-03-20 10:10:48 +00:00
``` sql
2020-02-02 21:59:23 +00:00
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;
2019-12-26 12:51:48 +00:00
```
2023-04-19 20:04:59 +00:00
```result
2019-12-26 12:51:48 +00:00
┌─key1────┬─key2─────┬─value─┐
│ Hello, │ World │ 1 │
│ Hello, │ World │ 2 │
│ Hello, │ World! │ 3 │
│ Hello │ , World! │ 2 │
└─────────┴──────────┴───────┘
```
2019-11-08 19:08:55 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT concat(key1, key2), sum(value) FROM key_val GROUP BY concatAssumeInjective(key1, key2);
2019-11-08 19:08:55 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2019-11-08 19:08:55 +00:00
┌─concat(key1, key2)─┬─sum(value)─┐
│ Hello, World! │ 3 │
│ Hello, World! │ 2 │
│ Hello, World │ 3 │
└────────────────────┴────────────┘
```
2019-01-30 10:39:46 +00:00
2023-04-19 20:04:59 +00:00
## concatWithSeparator
Concatenates the given strings with a given separator.
2017-04-03 19:49:50 +00:00
2023-04-19 20:04:59 +00:00
**Syntax**
``` sql
concatWithSeparator(sep, expr1, expr2, expr3...)
```
2017-04-03 19:49:50 +00:00
2023-11-15 15:42:00 +00:00
Alias: `concat_ws`
2023-04-19 20:04:59 +00:00
**Arguments**
2017-12-28 15:13:23 +00:00
2023-04-19 20:04:59 +00:00
- sep — separator. Const [String ](../../sql-reference/data-types/string.md ) or [FixedString ](../../sql-reference/data-types/fixedstring.md ).
- exprN — expression to be concatenated. [String ](../../sql-reference/data-types/string.md ) or [FixedString ](../../sql-reference/data-types/fixedstring.md ).
2017-04-03 19:49:50 +00:00
2023-04-19 20:04:59 +00:00
**Returned values**
2017-12-28 15:13:23 +00:00
2023-04-19 20:04:59 +00:00
The String created by concatenating the arguments.
2017-12-28 15:13:23 +00:00
2023-04-19 20:04:59 +00:00
If any of the argument values is `NULL` , the function returns `NULL` .
2017-12-28 15:13:23 +00:00
2023-04-19 20:04:59 +00:00
**Example**
2017-04-03 19:49:50 +00:00
2023-04-19 20:04:59 +00:00
``` sql
SELECT concatWithSeparator('a', '1', '2', '3', '4')
```
2022-06-22 09:56:37 +00:00
2023-04-19 20:04:59 +00:00
Result:
```result
┌─concatWithSeparator('a', '1', '2', '3', '4')─┐
2023-12-13 16:49:39 +00:00
│ 1a2a3a4 │
└──────────────────────────────────────────────┘
2023-04-19 20:04:59 +00:00
```
## 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.
2023-11-28 14:59:20 +00:00
## substring
2023-04-19 20:04:59 +00:00
2023-11-28 14:59:20 +00:00
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.
2023-04-19 20:04:59 +00:00
**Syntax**
```sql
2023-11-28 14:59:20 +00:00
substring(s, offset[, length])
2023-04-19 20:04:59 +00:00
```
Alias:
- `substr`
- `mid`
2023-11-28 14:59:20 +00:00
**Arguments**
- `s` — The string to calculate a substring from. [String ](../../sql-reference/data-types/string.md ), [FixedString ](../../sql-reference/data-types/fixedstring.md ) or [Enum ](../../sql-reference/data-types/enum.md )
- `offset` — The starting position of the substring in `s` . [(U)Int* ](../../sql-reference/data-types/int-uint.md ).
- `length` — The maximum length of the substring. [(U)Int* ](../../sql-reference/data-types/int-uint.md ). Optional.
**Returned value**
A substring of `s` with `length` many bytes, starting at index `offset` .
Type: `String` .
**Example**
``` sql
SELECT 'database' AS db, substr(db, 5), substr(db, 5, 1)
```
Result:
```result
┌─db───────┬─substring('database', 5)─┬─substring('database', 5, 1)─┐
│ database │ base │ b │
└──────────┴──────────────────────────┴─────────────────────────────┘
```
2023-04-19 20:04:59 +00:00
## substringUTF8
Like `substring` but 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.
2023-06-28 03:28:20 +00:00
2023-11-28 14:59:20 +00:00
## substringIndex
2023-06-28 03:28:20 +00:00
2023-06-29 02:18:47 +00:00
Returns the substring of `s` before `count` occurrences of the delimiter `delim` , as in Spark or MySQL.
2023-06-28 03:28:20 +00:00
**Syntax**
```sql
2023-06-29 02:19:04 +00:00
substringIndex(s, delim, count)
2023-06-28 03:28:20 +00:00
```
Alias: `SUBSTRING_INDEX`
**Arguments**
- s: The string to extract substring from. [String ](../../sql-reference/data-types/string.md ).
- delim: The character to split. [String ](../../sql-reference/data-types/string.md ).
2023-06-29 02:19:13 +00:00
- 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 ](../data-types/int-uint.md )
2023-06-28 03:28:20 +00:00
**Example**
``` sql
SELECT substringIndex('www.clickhouse.com', '.', 2)
```
Result:
```
┌─substringIndex('www.clickhouse.com', '.', 2)─┐
│ www.clickhouse │
└──────────────────────────────────────────────┘
```
2023-11-28 14:59:20 +00:00
## substringIndexUTF8
2023-06-28 03:28:20 +00:00
Like `substringIndex` but 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.
2023-04-19 20:04:59 +00:00
## appendTrailingCharIfAbsent
Appends character `c` to string `s` if `s` is non-empty and does not end with character `c` .
**Syntax**
```sql
appendTrailingCharIfAbsent(s, c)
```
## convertCharset
Returns string `s` converted from the encoding `from` to encoding `to` .
**Syntax**
```sql
convertCharset(s, from, to)
```
## base58Encode
Encodes a String using [Base58 ](https://tools.ietf.org/id/draft-msporny-base58-01.html ) in the "Bitcoin" alphabet.
2022-06-22 09:56:37 +00:00
**Syntax**
```sql
2022-08-30 14:08:23 +00:00
base58Encode(plaintext)
2022-06-22 09:56:37 +00:00
```
**Arguments**
2022-08-30 14:08:23 +00:00
- `plaintext` — [String ](../../sql-reference/data-types/string.md ) column or constant.
2022-06-22 09:56:37 +00:00
**Returned value**
2023-04-19 20:04:59 +00:00
- A string containing the encoded value of the argument.
2022-06-22 09:56:37 +00:00
Type: [String ](../../sql-reference/data-types/string.md ).
**Example**
``` sql
2022-07-16 17:45:33 +00:00
SELECT base58Encode('Encoded');
2022-08-30 14:08:23 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2022-08-30 14:08:23 +00:00
┌─base58Encode('Encoded')─┐
│ 3dc8KtHrwM │
└─────────────────────────┘
```
2023-04-19 20:04:59 +00:00
## base58Decode
2022-08-30 14:08:23 +00:00
Accepts a String and decodes it using [Base58 ](https://tools.ietf.org/id/draft-msporny-base58-01.html ) encoding scheme using "Bitcoin" alphabet.
**Syntax**
```sql
2023-04-19 20:04:59 +00:00
base58Decode(encoded)
2022-08-30 14:08:23 +00:00
```
**Arguments**
2023-04-19 20:04:59 +00:00
- `encoded` — [String ](../../sql-reference/data-types/string.md ) column or constant. If the string is not a valid Base58-encoded value, an exception is thrown.
2022-08-30 14:08:23 +00:00
**Returned value**
2023-04-19 20:04:59 +00:00
- A string containing the decoded value of the argument.
2022-08-30 14:08:23 +00:00
Type: [String ](../../sql-reference/data-types/string.md ).
**Example**
``` sql
2022-08-30 11:40:26 +00:00
SELECT base58Decode('3dc8KtHrwM');
2022-06-22 09:56:37 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2022-08-30 14:08:23 +00:00
┌─base58Decode('3dc8KtHrwM')─┐
│ Encoded │
└────────────────────────────┘
2022-06-22 09:56:37 +00:00
```
2023-04-19 20:04:59 +00:00
## tryBase58Decode
2022-09-27 08:52:08 +00:00
2023-04-19 20:04:59 +00:00
Like `base58Decode` but returns an empty string in case of error.
2022-09-27 08:52:08 +00:00
2023-04-19 20:04:59 +00:00
## base64Encode
2020-03-19 15:32:53 +00:00
2023-04-19 20:04:59 +00:00
Encodes a String or FixedString as base64.
2018-11-02 19:06:05 +00:00
2021-02-16 11:13:01 +00:00
Alias: `TO_BASE64` .
2023-04-19 20:04:59 +00:00
## base64Decode
2020-03-19 15:32:53 +00:00
2023-04-19 20:04:59 +00:00
Decodes a base64-encoded String or FixedString. Throws an exception in case of error.
2018-11-02 19:06:05 +00:00
2021-02-16 11:13:01 +00:00
Alias: `FROM_BASE64` .
2023-04-19 20:04:59 +00:00
## tryBase64Decode
2018-11-14 09:32:42 +00:00
2023-04-19 20:04:59 +00:00
Like `base64Decode` but returns an empty string in case of error.
2019-01-30 10:39:46 +00:00
2023-04-19 20:04:59 +00:00
## endsWith
2019-01-30 10:39:46 +00:00
2023-04-19 20:04:59 +00:00
Returns whether string `str` ends with `suffix` .
2019-01-30 10:39:46 +00:00
2023-04-19 20:04:59 +00:00
**Syntax**
2019-09-26 11:39:06 +00:00
2023-04-19 20:04:59 +00:00
```sql
endsWith(str, suffix)
2019-09-26 11:39:06 +00:00
```
2023-07-25 07:34:38 +00:00
## endsWithUTF8
2023-07-26 02:53:07 +00:00
Returns whether string `str` ends with `suffix` , the difference between `endsWithUTF8` and `endsWith` is that `endsWithUTF8` match `str` and `suffix` by UTF-8 characters.
2023-07-25 07:34:38 +00:00
**Syntax**
```sql
endsWithUTF8(str, suffix)
```
**Example**
``` sql
2023-07-31 04:07:50 +00:00
SELECT endsWithUTF8('中国', '\xbd'), endsWith('中国', '\xbd')
```
Result:
```result
┌─endsWithUTF8('中国', '½')─┬─endsWith('中国', '½')─┐
│ 0 │ 1 │
└──────────────────────────┴──────────────────────┘
2023-07-25 07:34:38 +00:00
```
2023-04-19 20:04:59 +00:00
## startsWith
2019-09-26 11:39:06 +00:00
2023-04-19 20:04:59 +00:00
Returns whether string `str` starts with `prefix` .
2019-09-26 11:39:06 +00:00
2023-04-19 20:04:59 +00:00
**Syntax**
2019-09-26 11:39:06 +00:00
2023-04-19 20:04:59 +00:00
```sql
startsWith(str, prefix)
2019-09-26 11:39:06 +00:00
```
2023-04-19 20:04:59 +00:00
**Example**
2019-09-26 11:39:06 +00:00
2023-04-19 20:04:59 +00:00
``` sql
SELECT startsWith('Spider-Man', 'Spi');
2019-09-26 11:39:06 +00:00
```
2019-01-30 10:39:46 +00:00
2023-07-25 07:34:38 +00:00
## startsWithUTF8
2023-07-26 02:53:07 +00:00
Returns whether string `str` starts with `prefix` , the difference between `startsWithUTF8` and `startsWith` is that `startsWithUTF8` match `str` and `suffix` by UTF-8 characters.
2023-07-25 07:34:38 +00:00
**Example**
``` sql
2023-07-31 04:07:50 +00:00
SELECT startsWithUTF8('中国', '\xe4'), startsWith('中国', '\xe4')
2023-07-25 07:34:38 +00:00
```
2023-07-31 04:07:50 +00:00
Result:
```result
┌─startsWithUTF8('中国', '⥩─┬─startsWith('中国', '⥩─┐
│ 0 │ 1 │
└────────────────────────────┴────────────────────────┘
```
2023-07-25 07:34:38 +00:00
2022-06-02 10:55:18 +00:00
## trim
2020-01-05 22:50:16 +00:00
2023-04-19 20:04:59 +00:00
Removes the specified characters from the start or end of a string. If not specified otherwise, the function removes whitespace (ASCII-character 32).
2020-01-05 22:50:16 +00:00
**Syntax**
2020-03-20 10:10:48 +00:00
``` sql
2020-01-05 22:50:16 +00:00
trim([[LEADING|TRAILING|BOTH] trim_character FROM] input_string)
```
2021-02-15 21:22:10 +00:00
**Arguments**
2020-01-05 22:50:16 +00:00
2023-04-19 15:55:29 +00:00
- `trim_character` — Specified characters for trim. [String ](../../sql-reference/data-types/string.md ).
- `input_string` — String for trim. [String ](../../sql-reference/data-types/string.md ).
2020-01-05 22:50:16 +00:00
**Returned value**
2023-04-19 20:04:59 +00:00
A string without leading and/or trailing specified characters.
2020-01-05 22:50:16 +00:00
Type: `String` .
**Example**
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT trim(BOTH ' ()' FROM '( Hello, world! )');
2020-01-05 22:50:16 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2020-01-05 22:50:16 +00:00
┌─trim(BOTH ' ()' FROM '( Hello, world! )')─┐
│ Hello, world! │
└───────────────────────────────────────────────┘
```
2022-06-02 10:55:18 +00:00
## trimLeft
2019-01-30 10:39:46 +00:00
2023-04-19 20:04:59 +00:00
Removes the consecutive occurrences of whitespace (ASCII-character 32) from the start of a string.
2019-01-30 10:39:46 +00:00
2020-03-20 10:10:48 +00:00
**Syntax**
2019-01-30 10:39:46 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2020-01-05 22:50:16 +00:00
trimLeft(input_string)
2019-12-05 10:03:35 +00:00
```
2020-01-05 22:50:16 +00:00
Alias: `ltrim(input_string)` .
2019-12-05 10:03:35 +00:00
2021-02-15 21:22:10 +00:00
**Arguments**
2019-12-05 10:03:35 +00:00
2023-04-19 15:55:29 +00:00
- `input_string` — string to trim. [String ](../../sql-reference/data-types/string.md ).
2019-12-05 10:03:35 +00:00
**Returned value**
A string without leading common whitespaces.
Type: `String` .
**Example**
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT trimLeft(' Hello, world! ');
2019-12-05 10:03:35 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2019-12-05 10:03:35 +00:00
┌─trimLeft(' Hello, world! ')─┐
│ Hello, world! │
└─────────────────────────────────────┘
```
2022-06-02 10:55:18 +00:00
## trimRight
2019-12-05 10:03:35 +00:00
2023-04-19 20:04:59 +00:00
Removes the consecutive occurrences of whitespace (ASCII-character 32) from the end of a string.
2019-12-05 10:03:35 +00:00
2020-03-20 10:10:48 +00:00
**Syntax**
2019-12-05 10:03:35 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2020-01-05 22:50:16 +00:00
trimRight(input_string)
2019-12-05 10:03:35 +00:00
```
2020-01-05 22:50:16 +00:00
Alias: `rtrim(input_string)` .
2019-12-05 10:03:35 +00:00
2021-02-15 21:22:10 +00:00
**Arguments**
2019-12-05 10:03:35 +00:00
2023-04-19 15:55:29 +00:00
- `input_string` — string to trim. [String ](../../sql-reference/data-types/string.md ).
2019-12-05 10:03:35 +00:00
**Returned value**
A string without trailing common whitespaces.
Type: `String` .
2019-01-30 10:39:46 +00:00
2019-12-05 10:03:35 +00:00
**Example**
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT trimRight(' Hello, world! ');
2019-12-05 10:03:35 +00:00
```
Result:
2019-01-30 10:39:46 +00:00
2023-04-19 20:04:59 +00:00
```result
2019-12-05 10:03:35 +00:00
┌─trimRight(' Hello, world! ')─┐
│ Hello, world! │
└──────────────────────────────────────┘
```
2022-06-02 10:55:18 +00:00
## trimBoth
2019-12-05 10:03:35 +00:00
2023-04-19 20:04:59 +00:00
Removes the consecutive occurrences of whitespace (ASCII-character 32) from both ends of a string.
2019-12-05 10:03:35 +00:00
2020-03-20 10:10:48 +00:00
**Syntax**
2019-12-05 10:03:35 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2020-01-05 22:50:16 +00:00
trimBoth(input_string)
2019-12-05 10:03:35 +00:00
```
2020-01-05 22:50:16 +00:00
Alias: `trim(input_string)` .
2019-12-05 10:03:35 +00:00
2021-02-15 21:22:10 +00:00
**Arguments**
2019-12-05 10:03:35 +00:00
2023-04-19 15:55:29 +00:00
- `input_string` — string to trim. [String ](../../sql-reference/data-types/string.md ).
2019-12-05 10:03:35 +00:00
**Returned value**
A string without leading and trailing common whitespaces.
Type: `String` .
**Example**
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT trimBoth(' Hello, world! ');
2019-12-05 10:03:35 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2019-12-05 10:03:35 +00:00
┌─trimBoth(' Hello, world! ')─┐
│ Hello, world! │
└─────────────────────────────────────┘
```
2019-01-30 10:39:46 +00:00
2023-04-19 20:04:59 +00:00
## CRC32
2019-06-17 21:49:37 +00:00
2023-04-19 20:04:59 +00:00
Returns the CRC32 checksum of a string using CRC-32-IEEE 802.3 polynomial and initial value `0xffffffff` (zlib implementation).
2019-10-20 20:04:52 +00:00
The result type is UInt32.
2023-04-19 20:04:59 +00:00
## CRC32IEEE
2019-10-20 20:04:52 +00:00
Returns the CRC32 checksum of a string, using CRC-32-IEEE 802.3 polynomial.
2019-06-17 21:49:37 +00:00
The result type is UInt32.
2023-04-19 20:04:59 +00:00
## CRC64
2019-10-20 20:04:52 +00:00
Returns the CRC64 checksum of a string, using CRC-64-ECMA polynomial.
The result type is UInt64.
2022-06-02 10:55:18 +00:00
## normalizeQuery
2020-09-26 07:07:16 +00:00
Replaces literals, sequences of literals and complex aliases with placeholders.
2021-03-13 18:18:45 +00:00
**Syntax**
2020-09-26 07:07:16 +00:00
``` sql
normalizeQuery(x)
```
2021-07-29 15:20:55 +00:00
**Arguments**
2020-09-26 07:07:16 +00:00
2023-04-19 15:55:29 +00:00
- `x` — Sequence of characters. [String ](../../sql-reference/data-types/string.md ).
2020-09-26 07:07:16 +00:00
2020-09-28 20:58:08 +00:00
**Returned value**
2020-09-26 07:07:16 +00:00
2023-04-19 15:55:29 +00:00
- Sequence of characters with placeholders.
2020-09-26 07:07:16 +00:00
Type: [String ](../../sql-reference/data-types/string.md ).
**Example**
``` sql
SELECT normalizeQuery('[1, 2, 3, x]') AS query;
```
Result:
2023-04-19 20:04:59 +00:00
```result
2020-09-26 07:07:16 +00:00
┌─query────┐
│ [?.., x] │
└──────────┘
```
2022-06-02 10:55:18 +00:00
## normalizedQueryHash
2020-09-26 07:07:16 +00:00
2023-04-19 20:04:59 +00:00
Returns identical 64bit hash values without the values of literals for similar queries. Can be helpful to analyze query log.
2020-09-26 07:07:16 +00:00
2021-07-29 15:20:55 +00:00
**Syntax**
2020-09-26 07:07:16 +00:00
``` sql
normalizedQueryHash(x)
```
2021-07-29 15:20:55 +00:00
**Arguments**
2020-09-26 07:07:16 +00:00
2023-04-19 15:55:29 +00:00
- `x` — Sequence of characters. [String ](../../sql-reference/data-types/string.md ).
2020-09-26 07:07:16 +00:00
**Returned value**
2023-04-19 15:55:29 +00:00
- Hash value.
2020-09-26 07:07:16 +00:00
Type: [UInt64 ](../../sql-reference/data-types/int-uint.md#uint-ranges ).
**Example**
``` sql
SELECT normalizedQueryHash('SELECT 1 AS `xyz` ') != normalizedQueryHash('SELECT 1 AS `abc` ') AS res;
```
Result:
2023-04-19 20:04:59 +00:00
```result
2020-09-26 07:07:16 +00:00
┌─res─┐
│ 1 │
└─────┘
```
2022-06-02 10:55:18 +00:00
## normalizeUTF8NFC
2021-10-19 22:31:39 +00:00
2023-04-19 20:04:59 +00:00
Converts a string to [NFC normalized form ](https://en.wikipedia.org/wiki/Unicode_equivalence#Normal_forms ), assuming the string is valid UTF8-encoded text.
2021-10-19 22:31:39 +00:00
**Syntax**
``` sql
2021-10-25 10:44:50 +00:00
normalizeUTF8NFC(words)
2021-10-19 22:31:39 +00:00
```
**Arguments**
2023-04-19 20:04:59 +00:00
- `words` — UTF8-encoded input string. [String ](../../sql-reference/data-types/string.md ).
2021-10-19 22:31:39 +00:00
**Returned value**
2023-04-19 15:55:29 +00:00
- String transformed to NFC normalization form.
2021-10-19 22:31:39 +00:00
Type: [String ](../../sql-reference/data-types/string.md ).
2021-10-22 20:10:02 +00:00
**Example**
``` sql
2021-10-25 09:46:50 +00:00
SELECT length('â'), normalizeUTF8NFC('â') AS nfc, length(nfc) AS nfc_len;
2021-10-22 20:10:02 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-10-25 09:46:50 +00:00
┌─length('â')─┬─nfc─┬─nfc_len─┐
│ 2 │ â │ 2 │
2021-10-22 20:10:02 +00:00
└─────────────┴─────┴─────────┘
```
2022-06-02 10:55:18 +00:00
## normalizeUTF8NFD
2021-10-22 20:10:02 +00:00
2023-04-19 20:04:59 +00:00
Converts a string to [NFD normalized form ](https://en.wikipedia.org/wiki/Unicode_equivalence#Normal_forms ), assuming the string is valid UTF8-encoded text.
2021-10-22 20:10:02 +00:00
**Syntax**
``` sql
normalizeUTF8NFD(words)
```
**Arguments**
2023-04-19 20:04:59 +00:00
- `words` — UTF8-encoded input string. [String ](../../sql-reference/data-types/string.md ).
2021-10-22 20:10:02 +00:00
**Returned value**
2023-04-19 15:55:29 +00:00
- String transformed to NFD normalization form.
2021-10-19 22:31:39 +00:00
2021-10-22 20:10:02 +00:00
Type: [String ](../../sql-reference/data-types/string.md ).
**Example**
``` sql
2021-10-25 09:46:50 +00:00
SELECT length('â'), normalizeUTF8NFD('â') AS nfd, length(nfd) AS nfd_len;
2021-10-22 20:10:02 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-10-25 09:46:50 +00:00
┌─length('â')─┬─nfd─┬─nfd_len─┐
│ 2 │ â │ 3 │
2021-10-22 20:10:02 +00:00
└─────────────┴─────┴─────────┘
```
2022-06-02 10:55:18 +00:00
## normalizeUTF8NFKC
2021-10-22 20:10:02 +00:00
2023-04-19 20:04:59 +00:00
Converts a string to [NFKC normalized form ](https://en.wikipedia.org/wiki/Unicode_equivalence#Normal_forms ), assuming the string is valid UTF8-encoded text.
2021-10-22 20:10:02 +00:00
**Syntax**
``` sql
normalizeUTF8NFKC(words)
```
**Arguments**
2023-04-19 20:04:59 +00:00
- `words` — UTF8-encoded input string. [String ](../../sql-reference/data-types/string.md ).
2021-10-22 20:10:02 +00:00
**Returned value**
2023-04-19 15:55:29 +00:00
- String transformed to NFKC normalization form.
2021-10-22 20:10:02 +00:00
Type: [String ](../../sql-reference/data-types/string.md ).
**Example**
``` sql
2021-10-25 09:46:50 +00:00
SELECT length('â'), normalizeUTF8NFKC('â') AS nfkc, length(nfkc) AS nfkc_len;
2021-10-22 20:10:02 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-10-25 09:46:50 +00:00
┌─length('â')─┬─nfkc─┬─nfkc_len─┐
│ 2 │ â │ 2 │
2021-10-22 20:10:02 +00:00
└─────────────┴──────┴──────────┘
```
2022-06-02 10:55:18 +00:00
## normalizeUTF8NFKD
2021-10-22 20:10:02 +00:00
2023-04-19 20:04:59 +00:00
Converts a string to [NFKD normalized form ](https://en.wikipedia.org/wiki/Unicode_equivalence#Normal_forms ), assuming the string is valid UTF8-encoded text.
2021-10-22 20:10:02 +00:00
**Syntax**
``` sql
normalizeUTF8NFKD(words)
```
**Arguments**
2023-04-19 20:04:59 +00:00
- `words` — UTF8-encoded input string. [String ](../../sql-reference/data-types/string.md ).
2021-10-22 20:10:02 +00:00
**Returned value**
2023-04-19 15:55:29 +00:00
- String transformed to NFKD normalization form.
2021-10-22 20:10:02 +00:00
Type: [String ](../../sql-reference/data-types/string.md ).
**Example**
``` sql
2021-10-25 09:46:50 +00:00
SELECT length('â'), normalizeUTF8NFKD('â') AS nfkd, length(nfkd) AS nfkd_len;
2021-10-22 20:10:02 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-10-25 09:46:50 +00:00
┌─length('â')─┬─nfkd─┬─nfkd_len─┐
│ 2 │ â │ 3 │
2021-10-22 20:10:02 +00:00
└─────────────┴──────┴──────────┘
```
2021-10-19 22:31:39 +00:00
2022-06-02 10:55:18 +00:00
## encodeXMLComponent
2020-12-27 11:21:58 +00:00
2023-04-19 20:04:59 +00:00
Escapes characters with special meaning in XML such that they can afterwards be place into a XML text node or attribute.
2020-12-27 11:21:58 +00:00
2023-04-19 20:04:59 +00:00
The following characters are replaced: `<` , `&` , `>` , `"` , `'` .
Also see the [list of XML and HTML character entity references ](https://en.wikipedia.org/wiki/List_of_XML_and_HTML_character_entity_references ).
2020-12-27 20:49:05 +00:00
2021-07-29 15:20:55 +00:00
**Syntax**
2020-12-27 11:21:58 +00:00
``` sql
encodeXMLComponent(x)
```
2021-07-29 15:20:55 +00:00
**Arguments**
2020-12-27 11:21:58 +00:00
2023-04-19 20:04:59 +00:00
- `x` — An input string. [String ](../../sql-reference/data-types/string.md ).
2020-12-27 11:21:58 +00:00
2021-01-18 15:24:17 +00:00
**Returned value**
2020-12-27 11:21:58 +00:00
2023-04-19 20:04:59 +00:00
- The escaped string.
2020-12-27 11:21:58 +00:00
Type: [String ](../../sql-reference/data-types/string.md ).
**Example**
``` sql
2020-12-27 20:49:05 +00:00
SELECT encodeXMLComponent('Hello, "world"!');
SELECT encodeXMLComponent('< 123 > ');
SELECT encodeXMLComponent('&clickhouse');
SELECT encodeXMLComponent('\'foo\'');
2020-12-27 11:21:58 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2020-12-27 20:49:05 +00:00
Hello, " world" !
< 123>
& clickhouse
' foo'
2020-12-27 11:21:58 +00:00
```
2022-06-02 10:55:18 +00:00
## decodeXMLComponent
2021-02-12 19:28:03 +00:00
2023-04-19 20:04:59 +00:00
Un-escapes substrings with special meaning in XML. These substrings are: `"` `&` `'` `>` `<`
2021-02-15 18:25:32 +00:00
This function also replaces numeric character references with Unicode characters. Both decimal (like `✓` ) and hexadecimal (`✓ `) forms are supported.
2021-02-12 19:28:03 +00:00
**Syntax**
``` sql
decodeXMLComponent(x)
```
2021-03-13 18:18:45 +00:00
**Arguments**
2021-02-12 19:28:03 +00:00
2023-04-19 20:04:59 +00:00
- `x` — An input string. [String ](../../sql-reference/data-types/string.md ).
2021-02-12 19:28:03 +00:00
**Returned value**
2023-04-19 20:04:59 +00:00
- The un-escaped string.
2021-02-12 19:28:03 +00:00
Type: [String ](../../sql-reference/data-types/string.md ).
**Example**
``` sql
SELECT decodeXMLComponent('' foo' ');
SELECT decodeXMLComponent('< Σ > ');
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-07-29 15:20:55 +00:00
'foo'
2021-02-12 19:28:03 +00:00
< Σ >
```
2023-08-31 04:42:51 +00:00
## 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**
``` sql
2023-12-14 02:54:52 +00:00
decodeHTMLComponent(x)
2023-08-31 04:42:51 +00:00
```
**Arguments**
- `x` — An input string. [String ](../../sql-reference/data-types/string.md ).
**Returned value**
- The un-escaped string.
Type: [String ](../../sql-reference/data-types/string.md ).
**Example**
``` sql
SELECT decodeHTMLComponent(''CH');
2023-12-14 04:32:12 +00:00
SELECT decodeHTMLComponent('I♥ ClickHouse');
2023-08-31 04:42:51 +00:00
```
Result:
```result
'CH'
I♥ClickHouse'
```
2022-06-02 10:55:18 +00:00
## extractTextFromHTML
2021-03-28 18:42:04 +00:00
2023-04-19 20:04:59 +00:00
This function extracts plain text from HTML or XHTML.
2021-04-06 18:52:06 +00:00
2023-04-19 20:04:59 +00:00
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:
1. Comments are skipped. Example: `<!-- test -->` . Comment must end with `-->` . Nested comments are disallowed.
2021-04-07 18:35:11 +00:00
Note: constructions like `<!-->` and `<!--->` are not valid comments in HTML but they are skipped by other rules.
2023-04-19 20:04:59 +00:00
2. CDATA is pasted verbatim. Note: CDATA is XML/XHTML-specific and processed on a "best-effort" basis.
2021-04-07 18:35:11 +00:00
3. `script` and `style` 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>"` .
2021-04-07 19:23:53 +00:00
Note: comments and CDATA are possible inside `script` or `style` - 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>`
2021-04-06 19:10:22 +00:00
Note: `script` and `style` can be the names of XML namespaces - then they are not treated like usual `script` or `style` elements. Example: `<script:a>Hello</script:a>` .
2021-04-06 18:52:06 +00:00
Note: whitespaces are possible after closing tag name: `</script >` but not before: `< / script>` .
4. Other tags or tag-like elements are skipped without inner content. Example: `<a>.</a>`
2021-04-07 18:35:11 +00:00
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 `
2021-04-06 19:10:22 +00:00
5. HTML and XML entities are not decoded. They must be processed by separate function.
6. 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.
2021-04-07 18:35:11 +00:00
- 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.
7. Also note that correct handling of whitespaces requires the support of `<pre></pre>` and CSS `display` and `white-space` properties.
2021-03-28 18:42:04 +00:00
**Syntax**
``` sql
extractTextFromHTML(x)
```
2021-04-03 16:16:56 +00:00
**Arguments**
2021-03-28 18:42:04 +00:00
2023-04-19 15:55:29 +00:00
- `x` — input text. [String ](../../sql-reference/data-types/string.md ).
2021-03-28 18:42:04 +00:00
**Returned value**
2023-04-19 15:55:29 +00:00
- Extracted text.
2021-03-28 18:42:04 +00:00
Type: [String ](../../sql-reference/data-types/string.md ).
**Example**
2021-04-03 19:31:24 +00:00
The first example contains several tags and a comment and also shows whitespace processing.
2021-04-05 20:19:18 +00:00
The second example shows `CDATA` and `script` tag processing.
2021-04-07 18:35:11 +00:00
In the third example text is extracted from the full HTML response received by the [url ](../../sql-reference/table-functions/url.md ) function.
2021-04-03 16:16:56 +00:00
2021-03-28 18:42:04 +00:00
``` sql
2021-04-05 20:53:55 +00:00
SELECT extractTextFromHTML(' < p > A text < i > with< / i > < b > tags< / b > . <!-- comments --> < / p > ');
2021-04-03 16:16:56 +00:00
SELECT extractTextFromHTML('<![CDATA[The content within <b>CDATA</b>]]> < script > alert ( "Script" ) ; < / script > ');
2021-04-05 19:37:01 +00:00
SELECT extractTextFromHTML(html) FROM url('http://www.donothingfor2minutes.com/', RawBLOB, 'html String');
2021-03-28 18:42:04 +00:00
```
Result:
2023-04-19 20:04:59 +00:00
```result
2021-04-05 20:53:55 +00:00
A text with tags .
2021-04-03 16:16:56 +00:00
The content within < b > CDATA< / b >
2021-04-05 19:37:01 +00:00
Do Nothing for 2 Minutes 2:00
2021-04-03 16:16:56 +00:00
```
2022-10-25 04:07:07 +00:00
2023-04-19 20:04:59 +00:00
## ascii {#ascii}
2022-10-25 04:07:07 +00:00
2023-04-19 20:04:59 +00:00
Returns the ASCII code point (as Int32) of the first character of string `s` .
2022-10-25 04:07:07 +00:00
2023-04-19 20:04:59 +00:00
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.
2022-12-01 02:56:53 +00:00
**Syntax**
2023-04-19 20:04:59 +00:00
```sql
ascii(s)
2022-12-01 02:56:53 +00:00
```
2023-04-09 09:00:20 +00:00
## soundex
2023-04-12 22:41:26 +00:00
Returns the [Soundex code ](https://en.wikipedia.org/wiki/Soundex ) of a string.
2023-04-09 09:00:20 +00:00
**Syntax**
``` sql
2023-04-12 22:41:26 +00:00
soundex(val)
2023-04-09 09:00:20 +00:00
```
**Arguments**
2023-04-12 22:41:26 +00:00
- `val` - Input value. [String ](../data-types/string.md )
2023-04-09 09:00:20 +00:00
**Returned value**
2023-04-12 22:41:26 +00:00
- The Soundex code of the input value. [String ](../data-types/string.md )
2023-04-09 09:00:20 +00:00
**Example**
``` sql
select soundex('aksel');
```
Result:
2023-04-19 20:04:59 +00:00
```result
2023-04-09 09:00:20 +00:00
┌─soundex('aksel')─┐
│ A240 │
└──────────────────┘
```
2023-06-30 13:11:06 +00:00
2023-11-06 09:59:12 +00:00
## byteHammingDistance
Calculates the [hamming distance ](https://en.wikipedia.org/wiki/Hamming_distance ) between two byte strings.
**Syntax**
```sql
byteHammingDistance(string1, string2)
```
**Examples**
``` sql
SELECT byteHammingDistance('karolin', 'kathrin');
```
Result:
``` text
┌─byteHammingDistance('karolin', 'kathrin')─┐
│ 3 │
└───────────────────────────────────────────┘
```
Alias: mismatches
## stringJaccardIndex
Calculates the [Jaccard similarity index ](https://en.wikipedia.org/wiki/Jaccard_index ) between two byte strings.
**Syntax**
```sql
stringJaccardIndex(string1, string2)
```
**Examples**
``` sql
SELECT stringJaccardIndex('clickhouse', 'mouse');
```
Result:
``` text
┌─stringJaccardIndex('clickhouse', 'mouse')─┐
│ 0.4 │
└───────────────────────────────────────────┘
```
## stringJaccardIndexUTF8
Like [stringJaccardIndex ](#stringJaccardIndex ) but for UTF8-encoded strings.
## editDistance
Calculates the [edit distance ](https://en.wikipedia.org/wiki/Edit_distance ) between two byte strings.
**Syntax**
```sql
editDistance(string1, string2)
```
**Examples**
``` sql
SELECT editDistance('clickhouse', 'mouse');
```
Result:
``` text
┌─editDistance('clickhouse', 'mouse')─┐
│ 6 │
└─────────────────────────────────────┘
```
Alias: levenshteinDistance
2023-06-30 13:11:06 +00:00
## initcap
2023-07-03 11:37:55 +00:00
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.
## initcapUTF8
Like [initcap ](#initcap ), assuming that the string contains valid UTF-8 encoded text. If this assumption is violated, no exception is thrown and the result is undefined.
Does not detect the language, e.g. for Turkish the result might not be exactly correct (i/İ vs. i/I).
2023-07-03 11:50:26 +00:00
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.
2023-07-17 11:58:27 +00:00
## firstLine
Returns the first line from a multi-line string.
**Syntax**
```sql
firstLine(val)
```
**Arguments**
- `val` - Input value. [String ](../data-types/string.md )
**Returned value**
- The first line of the input value or the whole value if there is no line
separators. [String ](../data-types/string.md )
**Example**
```sql
select firstLine('foo\nbar\nbaz');
```
Result:
```result
┌─firstLine('foo\nbar\nbaz')─┐
│ foo │
└────────────────────────────┘
```