ClickHouse/docs/en/sql-reference/functions/encoding-functions.md
2024-05-24 05:54:16 +02:00

18 KiB
Raw Blame History

slug sidebar_position sidebar_label
/en/sql-reference/functions/encoding-functions 65 Encoding

Encoding Functions

char

Returns the string with the length as the number of passed arguments and each byte has the value of corresponding argument. Accepts multiple arguments of numeric types. If the value of argument is out of range of UInt8 data type, it is converted to UInt8 with possible rounding and overflow.

Syntax

char(number_1, [number_2, ..., number_n]);

Arguments

  • number_1, number_2, ..., number_n — Numerical arguments interpreted as integers. Types: Int, Float.

Returned value

  • a string of given bytes. String.

Example

Query:

SELECT char(104.1, 101, 108.9, 108.9, 111) AS hello;

Result:

┌─hello─┐
│ hello │
└───────┘

You can construct a string of arbitrary encoding by passing the corresponding bytes. Here is example for UTF-8:

Query:

SELECT char(0xD0, 0xBF, 0xD1, 0x80, 0xD0, 0xB8, 0xD0, 0xB2, 0xD0, 0xB5, 0xD1, 0x82) AS hello;

Result:

┌─hello──┐
│ привет │
└────────┘

Query:

SELECT char(0xE4, 0xBD, 0xA0, 0xE5, 0xA5, 0xBD) AS hello;

Result:

┌─hello─┐
│ 你好  │
└───────┘

hex

Returns a string containing the arguments hexadecimal representation.

Alias: HEX.

Syntax

hex(arg)

The function is using uppercase letters A-F and not using any prefixes (like 0x) or suffixes (like h).

For integer arguments, it prints hex digits (“nibbles”) from the most significant to least significant (big-endian or “human-readable” order). It starts with the most significant non-zero byte (leading zero bytes are omitted) but always prints both digits of every byte even if the leading digit is zero.

Values of type Date and DateTime are formatted as corresponding integers (the number of days since Epoch for Date and the value of Unix Timestamp for DateTime).

For String and FixedString, all bytes are simply encoded as two hexadecimal numbers. Zero bytes are not omitted.

Values of Float and Decimal types are encoded as their representation in memory. As we support little-endian architecture, they are encoded in little-endian. Zero leading/trailing bytes are not omitted.

Values of UUID type are encoded as big-endian order string.

Arguments

Returned value

  • A string with the hexadecimal representation of the argument. String.

Examples

Query:

SELECT hex(1);

Result:

01

Query:

SELECT hex(toFloat32(number)) AS hex_presentation FROM numbers(15, 2);

Result:

┌─hex_presentation─┐
│ 00007041         │
│ 00008041         │
└──────────────────┘

Query:

SELECT hex(toFloat64(number)) AS hex_presentation FROM numbers(15, 2);

Result:

┌─hex_presentation─┐
│ 0000000000002E40 │
│ 0000000000003040 │
└──────────────────┘

Query:

SELECT lower(hex(toUUID('61f0c404-5cb3-11e7-907b-a6006ad3dba0'))) as uuid_hex

Result:

┌─uuid_hex─────────────────────────┐
│ 61f0c4045cb311e7907ba6006ad3dba0 │
└──────────────────────────────────┘

unhex

Performs the opposite operation of hex. It interprets each pair of hexadecimal digits (in the argument) as a number and converts it to the byte represented by the number. The return value is a binary string (BLOB).

If you want to convert the result to a number, you can use the reverse and reinterpretAs<Type> functions.

:::note
If unhex is invoked from within the clickhouse-client, binary strings display using UTF-8. :::

Alias: UNHEX.

Syntax

unhex(arg)

Arguments

Supports both uppercase and lowercase letters A-F. The number of hexadecimal digits does not have to be even. If it is odd, the last digit is interpreted as the least significant half of the 00-0F byte. If the argument string contains anything other than hexadecimal digits, some implementation-defined result is returned (an exception isnt thrown). For a numeric argument the inverse of hex(N) is not performed by unhex().

Returned value

  • A binary string (BLOB). String.

Example

Query:

SELECT unhex('303132'), UNHEX('4D7953514C');

Result:

┌─unhex('303132')─┬─unhex('4D7953514C')─┐
│ 012             │ MySQL               │
└─────────────────┴─────────────────────┘

Query:

SELECT reinterpretAsUInt64(reverse(unhex('FFF'))) AS num;

Result:

┌──num─┐
│ 4095 │
└──────┘

bin

Returns a string containing the arguments binary representation.

Syntax

bin(arg)

Alias: BIN.

For integer arguments, it prints bin digits from the most significant to least significant (big-endian or “human-readable” order). It starts with the most significant non-zero byte (leading zero bytes are omitted) but always prints eight digits of every byte if the leading digit is zero.

Values of type Date and DateTime are formatted as corresponding integers (the number of days since Epoch for Date and the value of Unix Timestamp for DateTime).

For String and FixedString, all bytes are simply encoded as eight binary numbers. Zero bytes are not omitted.

Values of Float and Decimal types are encoded as their representation in memory. As we support little-endian architecture, they are encoded in little-endian. Zero leading/trailing bytes are not omitted.

Values of UUID type are encoded as big-endian order string.

Arguments

Returned value

  • A string with the binary representation of the argument. String.

Examples

Query:

SELECT bin(14);

Result:

┌─bin(14)──┐
│ 00001110 │
└──────────┘

Query:

SELECT bin(toFloat32(number)) AS bin_presentation FROM numbers(15, 2);

Result:

┌─bin_presentation─────────────────┐
│ 00000000000000000111000001000001 │
│ 00000000000000001000000001000001 │
└──────────────────────────────────┘

Query:

SELECT bin(toFloat64(number)) AS bin_presentation FROM numbers(15, 2);

Result:

┌─bin_presentation─────────────────────────────────────────────────┐
│ 0000000000000000000000000000000000000000000000000010111001000000 │
│ 0000000000000000000000000000000000000000000000000011000001000000 │
└──────────────────────────────────────────────────────────────────┘

Query:

SELECT bin(toUUID('61f0c404-5cb3-11e7-907b-a6006ad3dba0')) as bin_uuid

Result:

┌─bin_uuid─────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────┐
│ 01100001111100001100010000000100010111001011001100010001111001111001000001111011101001100000000001101010110100111101101110100000 │
└──────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────┘

unbin

Interprets each pair of binary digits (in the argument) as a number and converts it to the byte represented by the number. The functions performs the opposite operation to bin.

Syntax

unbin(arg)

Alias: UNBIN.

For a numeric argument unbin() does not return the inverse of bin(). If you want to convert the result to a number, you can use the reverse and reinterpretAs<Type> functions.

:::note
If unbin is invoked from within the clickhouse-client, binary strings are displayed using UTF-8. :::

Supports binary digits 0 and 1. The number of binary digits does not have to be multiples of eight. If the argument string contains anything other than binary digits, some implementation-defined result is returned (an exception isnt thrown).

Arguments

  • arg — A string containing any number of binary digits. String.

Returned value

  • A binary string (BLOB). String.

Examples

Query:

SELECT UNBIN('001100000011000100110010'), UNBIN('0100110101111001010100110101000101001100');

Result:

┌─unbin('001100000011000100110010')─┬─unbin('0100110101111001010100110101000101001100')─┐
│ 012                               │ MySQL                                             │
└───────────────────────────────────┴───────────────────────────────────────────────────┘

Query:

SELECT reinterpretAsUInt64(reverse(unbin('1110'))) AS num;

Result:

┌─num─┐
│  14 │
└─────┘

bitmaskToList(num)

Accepts an integer. Returns a string containing the list of powers of two that total the source number when summed. They are comma-separated without spaces in text format, in ascending order.

bitmaskToArray(num)

Accepts an integer. Returns an array of UInt64 numbers containing the list of powers of two that total the source number when summed. Numbers in the array are in ascending order.

bitPositionsToArray(num)

Accepts an integer and converts it to an unsigned integer. Returns an array of UInt64 numbers containing the list of positions of bits of arg that equal 1, in ascending order.

Syntax

bitPositionsToArray(arg)

Arguments

Returned value

  • An array containing a list of positions of bits that equal 1, in ascending order. Array(UInt64).

Example

Query:

SELECT bitPositionsToArray(toInt8(1)) AS bit_positions;

Result:

┌─bit_positions─┐
│ [0]           │
└───────────────┘

Query:

SELECT bitPositionsToArray(toInt8(-1)) AS bit_positions;

Result:

┌─bit_positions─────┐
│ [0,1,2,3,4,5,6,7] │
└───────────────────┘

mortonEncode

Calculates the Morton encoding (ZCurve) for a list of unsigned integers.

The function has two modes of operation:

  • Simple
  • Expanded

Simple mode

Accepts up to 8 unsigned integers as arguments and produces a UInt64 code.

Syntax

mortonEncode(args)

Parameters

Returned value

Example

Query:

SELECT mortonEncode(1, 2, 3);

Result:

53

Expanded mode

Accepts a range mask (tuple) as a first argument and up to 8 unsigned integers as other arguments.

Each number in the mask configures the amount of range expansion:
1 - no expansion
2 - 2x expansion
3 - 3x expansion
...
Up to 8x expansion.

Syntax

mortonEncode(range_mask, args)

Parameters

  • range_mask: 1-8.
  • args: up to 8 unsigned integers or columns of the aforementioned type.

Note: when using columns for args the provided range_mask tuple should still be a constant.

Returned value

Example

Range expansion can be beneficial when you need a similar distribution for arguments with wildly different ranges (or cardinality) For example: 'IP Address' (0...FFFFFFFF) and 'Country code' (0...FF).

Query:

SELECT mortonEncode((1,2), 1024, 16);

Result:

1572864

Note: tuple size must be equal to the number of the other arguments.

Example

Morton encoding for one argument is always the argument itself:

Query:

SELECT mortonEncode(1);

Result:

1

Example

It is also possible to expand one argument too:

Query:

SELECT mortonEncode(tuple(2), 128);

Result:

32768

Example

You can also use column names in the function.

Query:

First create the table and insert some data.

create table morton_numbers(
    n1 UInt32,
    n2 UInt32,
    n3 UInt16,
    n4 UInt16,
    n5 UInt8,
    n6 UInt8,
    n7 UInt8,
    n8 UInt8
)
Engine=MergeTree()
ORDER BY n1 SETTINGS index_granularity = 8192, index_granularity_bytes = '10Mi';
insert into morton_numbers (*) values(1,2,3,4,5,6,7,8);

Use column names instead of constants as function arguments to mortonEncode

Query:

SELECT mortonEncode(n1, n2, n3, n4, n5, n6, n7, n8) FROM morton_numbers;

Result:

2155374165

implementation details

Please note that you can fit only so many bits of information into Morton code as UInt64 has. Two arguments will have a range of maximum 2^32 (64/2) each, three arguments a range of max 2^21 (64/3) each and so on. All overflow will be clamped to zero.

mortonDecode

Decodes a Morton encoding (ZCurve) into the corresponding unsigned integer tuple.

As with the mortonEncode function, this function has two modes of operation:

  • Simple
  • Expanded

Simple mode

Accepts a resulting tuple size as the first argument and the code as the second argument.

Syntax

mortonDecode(tuple_size, code)

Parameters

  • tuple_size: integer value no more than 8.
  • code: UInt64 code.

Returned value

Example

Query:

SELECT mortonDecode(3, 53);

Result:

["1","2","3"]

Expanded mode

Accepts a range mask (tuple) as a first argument and the code as the second argument. Each number in the mask configures the amount of range shrink:
1 - no shrink
2 - 2x shrink
3 - 3x shrink
...
Up to 8x shrink.

Range expansion can be beneficial when you need a similar distribution for arguments with wildly different ranges (or cardinality) For example: 'IP Address' (0...FFFFFFFF) and 'Country code' (0...FF). As with the encode function, this is limited to 8 numbers at most.

Example

Query:

SELECT mortonDecode(1, 1);

Result:

["1"]

Example

It is also possible to shrink one argument:

Query:

SELECT mortonDecode(tuple(2), 32768);

Result:

["128"]

Example

You can also use column names in the function.

First create the table and insert some data.

Query:

create table morton_numbers(
    n1 UInt32,
    n2 UInt32,
    n3 UInt16,
    n4 UInt16,
    n5 UInt8,
    n6 UInt8,
    n7 UInt8,
    n8 UInt8
)
Engine=MergeTree()
ORDER BY n1 SETTINGS index_granularity = 8192, index_granularity_bytes = '10Mi';
insert into morton_numbers (*) values(1,2,3,4,5,6,7,8);

Use column names instead of constants as function arguments to mortonDecode

Query:

select untuple(mortonDecode(8, mortonEncode(n1, n2, n3, n4, n5, n6, n7, n8))) from morton_numbers;

Result:

1	2	3	4	5	6	7	8