2020-04-03 13:23:32 +00:00
---
2022-04-09 13:29:05 +00:00
sidebar_position: 55
sidebar_label: IP Addresses
2020-04-03 13:23:32 +00:00
---
2022-06-02 10:55:18 +00:00
# Functions for Working with IPv4 and IPv6 Addresses
2017-12-28 15:13:23 +00:00
2022-06-02 10:55:18 +00:00
## IPv4NumToString(num)
2017-12-28 15:13:23 +00:00
Takes a UInt32 number. Interprets it as an IPv4 address in big endian. Returns a string containing the corresponding IPv4 address in the format A.B.C.d (dot-separated numbers in decimal form).
2021-02-16 11:13:17 +00:00
Alias: `INET_NTOA` .
2022-06-02 10:55:18 +00:00
## IPv4StringToNum(s)
2017-12-28 15:13:23 +00:00
2022-04-29 11:33:51 +00:00
The reverse function of IPv4NumToString. If the IPv4 address has an invalid format, it throws exception.
2017-12-28 15:13:23 +00:00
2021-02-16 11:13:17 +00:00
Alias: `INET_ATON` .
2022-06-02 10:55:18 +00:00
## IPv4StringToNumOrDefault(s)
2022-04-29 11:33:51 +00:00
Same as `IPv4StringToNum` , but if the IPv4 address has an invalid format, it returns 0.
2022-06-02 10:55:18 +00:00
## IPv4StringToNumOrNull(s)
2022-04-29 11:33:51 +00:00
Same as `IPv4StringToNum` , but if the IPv4 address has an invalid format, it returns null.
2022-06-02 10:55:18 +00:00
## IPv4NumToStringClassC(num)
2017-12-28 15:13:23 +00:00
Similar to IPv4NumToString, but using xxx instead of the last octet.
Example:
2020-03-20 10:10:48 +00:00
``` sql
2017-12-28 15:13:23 +00:00
SELECT
IPv4NumToStringClassC(ClientIP) AS k,
count() AS c
FROM test.hits
GROUP BY k
ORDER BY c DESC
LIMIT 10
```
2020-03-20 10:10:48 +00:00
``` text
2017-12-28 15:13:23 +00:00
┌─k──────────────┬─────c─┐
│ 83.149.9.xxx │ 26238 │
│ 217.118.81.xxx │ 26074 │
│ 213.87.129.xxx │ 25481 │
│ 83.149.8.xxx │ 24984 │
│ 217.118.83.xxx │ 22797 │
│ 78.25.120.xxx │ 22354 │
│ 213.87.131.xxx │ 21285 │
│ 78.25.121.xxx │ 20887 │
│ 188.162.65.xxx │ 19694 │
│ 83.149.48.xxx │ 17406 │
└────────────────┴───────┘
```
2021-05-27 19:44:11 +00:00
Since using ‘ xxx’ is highly unusual, this may be changed in the future. We recommend that you do not rely on the exact format of this fragment.
2017-12-28 15:13:23 +00:00
2022-06-02 10:55:18 +00:00
### IPv6NumToString(x)
2017-12-28 15:13:23 +00:00
Accepts a FixedString(16) value containing the IPv6 address in binary format. Returns a string containing this address in text format.
2021-07-29 15:20:55 +00:00
IPv6-mapped IPv4 addresses are output in the format ::ffff:111.222.33.44.
2021-02-16 11:13:17 +00:00
Alias: `INET6_NTOA` .
Examples:
2017-12-28 15:13:23 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT IPv6NumToString(toFixedString(unhex('2A0206B8000000000000000000000011'), 16)) AS addr;
2017-12-28 15:13:23 +00:00
```
2020-03-20 10:10:48 +00:00
``` text
2017-12-28 15:13:23 +00:00
┌─addr─────────┐
│ 2a02:6b8::11 │
└──────────────┘
```
2020-03-20 10:10:48 +00:00
``` sql
2017-12-28 15:13:23 +00:00
SELECT
IPv6NumToString(ClientIP6 AS k),
count() AS c
FROM hits_all
WHERE EventDate = today() AND substring(ClientIP6, 1, 12) != unhex('00000000000000000000FFFF')
GROUP BY k
ORDER BY c DESC
LIMIT 10
```
2020-03-20 10:10:48 +00:00
``` text
2017-12-28 15:13:23 +00:00
┌─IPv6NumToString(ClientIP6)──────────────┬─────c─┐
│ 2a02:2168:aaa:bbbb::2 │ 24695 │
│ 2a02:2698:abcd:abcd:abcd:abcd:8888:5555 │ 22408 │
│ 2a02:6b8:0:fff::ff │ 16389 │
│ 2a01:4f8:111:6666::2 │ 16016 │
│ 2a02:2168:888:222::1 │ 15896 │
│ 2a01:7e00::ffff:ffff:ffff:222 │ 14774 │
│ 2a02:8109:eee:ee:eeee:eeee:eeee:eeee │ 14443 │
│ 2a02:810b:8888:888:8888:8888:8888:8888 │ 14345 │
│ 2a02:6b8:0:444:4444:4444:4444:4444 │ 14279 │
│ 2a01:7e00::ffff:ffff:ffff:ffff │ 13880 │
└─────────────────────────────────────────┴───────┘
```
2020-03-20 10:10:48 +00:00
``` sql
2017-12-28 15:13:23 +00:00
SELECT
IPv6NumToString(ClientIP6 AS k),
count() AS c
FROM hits_all
WHERE EventDate = today()
GROUP BY k
ORDER BY c DESC
LIMIT 10
```
2020-03-20 10:10:48 +00:00
``` text
2017-12-28 15:13:23 +00:00
┌─IPv6NumToString(ClientIP6)─┬──────c─┐
│ ::ffff:94.26.111.111 │ 747440 │
│ ::ffff:37.143.222.4 │ 529483 │
│ ::ffff:5.166.111.99 │ 317707 │
│ ::ffff:46.38.11.77 │ 263086 │
│ ::ffff:79.105.111.111 │ 186611 │
│ ::ffff:93.92.111.88 │ 176773 │
│ ::ffff:84.53.111.33 │ 158709 │
│ ::ffff:217.118.11.22 │ 154004 │
│ ::ffff:217.118.11.33 │ 148449 │
│ ::ffff:217.118.11.44 │ 148243 │
└────────────────────────────┴────────┘
```
2022-06-02 10:55:18 +00:00
## IPv6StringToNum
2017-12-28 15:13:23 +00:00
2022-04-29 11:33:51 +00:00
The reverse function of [IPv6NumToString ](#ipv6numtostringx ). If the IPv6 address has an invalid format, it throws exception.
2021-03-05 14:50:43 +00:00
If the input string contains a valid IPv4 address, returns its IPv6 equivalent.
2017-12-28 15:13:23 +00:00
HEX can be uppercase or lowercase.
2021-02-16 11:13:17 +00:00
Alias: `INET6_ATON` .
2021-03-05 14:50:43 +00:00
**Syntax**
2021-01-26 03:04:08 +00:00
``` sql
2021-03-05 14:50:43 +00:00
IPv6StringToNum(string)
2021-01-26 03:04:08 +00:00
```
2021-07-29 15:20:55 +00:00
**Argument**
2021-03-05 14:50:43 +00:00
- `string` — IP address. [String ](../../sql-reference/data-types/string.md ).
**Returned value**
2021-07-29 15:20:55 +00:00
- IPv6 address in binary format.
2021-03-05 14:50:43 +00:00
Type: [FixedString(16) ](../../sql-reference/data-types/fixedstring.md ).
**Example**
Query:
``` sql
SELECT addr, cutIPv6(IPv6StringToNum(addr), 0, 0) FROM (SELECT ['notaddress', '127.0.0.1', '1111::ffff'] AS addr) ARRAY JOIN addr;
```
Result:
2021-01-26 03:04:08 +00:00
``` text
2021-03-05 14:50:43 +00:00
┌─addr───────┬─cutIPv6(IPv6StringToNum(addr), 0, 0)─┐
│ notaddress │ :: │
│ 127.0.0.1 │ ::ffff:127.0.0.1 │
│ 1111::ffff │ 1111::ffff │
└────────────┴──────────────────────────────────────┘
2021-01-26 03:04:08 +00:00
```
2021-03-13 18:18:45 +00:00
**See Also**
2021-03-05 14:50:43 +00:00
- [cutIPv6 ](#cutipv6x-bytestocutforipv6-bytestocutforipv4 ).
2022-06-02 10:55:18 +00:00
## IPv6StringToNumOrDefault(s)
2022-04-29 11:33:51 +00:00
Same as `IPv6StringToNum` , but if the IPv6 address has an invalid format, it returns 0.
2022-06-02 10:55:18 +00:00
## IPv6StringToNumOrNull(s)
2022-04-29 11:33:51 +00:00
Same as `IPv6StringToNum` , but if the IPv6 address has an invalid format, it returns null.
2022-06-02 10:55:18 +00:00
## IPv4ToIPv6(x)
2019-01-30 10:39:46 +00:00
2019-06-14 10:29:16 +00:00
Takes a `UInt32` number. Interprets it as an IPv4 address in [big endian ](https://en.wikipedia.org/wiki/Endianness ). Returns a `FixedString(16)` value containing the IPv6 address in binary format. Examples:
2019-01-30 10:39:46 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT IPv6NumToString(IPv4ToIPv6(IPv4StringToNum('192.168.0.1'))) AS addr;
2019-01-30 10:39:46 +00:00
```
2020-03-20 10:10:48 +00:00
``` text
2019-01-30 10:39:46 +00:00
┌─addr───────────────┐
│ ::ffff:192.168.0.1 │
└────────────────────┘
```
2022-06-02 10:55:18 +00:00
## cutIPv6(x, bytesToCutForIPv6, bytesToCutForIPv4)
2019-01-30 10:39:46 +00:00
2020-04-03 10:25:59 +00:00
Accepts a FixedString(16) value containing the IPv6 address in binary format. Returns a string containing the address of the specified number of bytes removed in text format. For example:
2019-01-30 10:39:46 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2019-01-30 10:39:46 +00:00
WITH
IPv6StringToNum('2001:0DB8:AC10:FE01:FEED:BABE:CAFE:F00D') AS ipv6,
IPv4ToIPv6(IPv4StringToNum('192.168.0.1')) AS ipv4
SELECT
cutIPv6(ipv6, 2, 0),
cutIPv6(ipv4, 0, 2)
```
2020-03-20 10:10:48 +00:00
``` text
2019-01-30 10:39:46 +00:00
┌─cutIPv6(ipv6, 2, 0)─────────────────┬─cutIPv6(ipv4, 0, 2)─┐
│ 2001:db8:ac10:fe01:feed:babe:cafe:0 │ ::ffff:192.168.0.0 │
└─────────────────────────────────────┴─────────────────────┘
```
2018-10-16 10:47:17 +00:00
2022-06-02 10:55:18 +00:00
## IPv4CIDRToRange(ipv4, Cidr),
2019-04-24 06:20:02 +00:00
2019-06-14 10:29:16 +00:00
Accepts an IPv4 and an UInt8 value containing the [CIDR ](https://en.wikipedia.org/wiki/Classless_Inter-Domain_Routing ). Return a tuple with two IPv4 containing the lower range and the higher range of the subnet.
2019-04-24 06:20:02 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT IPv4CIDRToRange(toIPv4('192.168.5.2'), 16);
2019-04-24 06:20:02 +00:00
```
2020-03-20 10:10:48 +00:00
``` text
2019-06-13 09:11:35 +00:00
┌─IPv4CIDRToRange(toIPv4('192.168.5.2'), 16)─┐
│ ('192.168.0.0','192.168.255.255') │
└────────────────────────────────────────────┘
2019-04-24 06:20:02 +00:00
```
2022-06-02 10:55:18 +00:00
## IPv6CIDRToRange(ipv6, Cidr),
2019-04-24 06:20:02 +00:00
2019-04-26 06:30:07 +00:00
Accepts an IPv6 and an UInt8 value containing the CIDR. Return a tuple with two IPv6 containing the lower range and the higher range of the subnet.
2019-04-24 06:20:02 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2019-06-13 09:11:35 +00:00
SELECT IPv6CIDRToRange(toIPv6('2001:0db8:0000:85a3:0000:0000:ac1f:8001'), 32);
2019-04-24 06:20:02 +00:00
```
2020-03-20 10:10:48 +00:00
``` text
2019-06-13 09:11:35 +00:00
┌─IPv6CIDRToRange(toIPv6('2001:0db8:0000:85a3:0000:0000:ac1f:8001'), 32)─┐
│ ('2001:db8::','2001:db8:ffff:ffff:ffff:ffff:ffff:ffff') │
└────────────────────────────────────────────────────────────────────────┘
2019-04-24 06:20:02 +00:00
```
2022-06-02 10:55:18 +00:00
## toIPv4(string)
2019-05-06 17:33:14 +00:00
2020-04-30 18:19:18 +00:00
An alias to `IPv4StringToNum()` that takes a string form of IPv4 address and returns value of [IPv4 ](../../sql-reference/data-types/domains/ipv4.md ) type, which is binary equal to value returned by `IPv4StringToNum()` .
2019-05-06 17:33:14 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2019-05-06 17:33:14 +00:00
WITH
'171.225.130.45' as IPv4_string
SELECT
toTypeName(IPv4StringToNum(IPv4_string)),
toTypeName(toIPv4(IPv4_string))
```
2020-03-20 10:10:48 +00:00
``` text
2019-05-06 17:33:14 +00:00
┌─toTypeName(IPv4StringToNum(IPv4_string))─┬─toTypeName(toIPv4(IPv4_string))─┐
│ UInt32 │ IPv4 │
└──────────────────────────────────────────┴─────────────────────────────────┘
```
2020-03-20 10:10:48 +00:00
``` sql
2019-05-06 17:33:14 +00:00
WITH
'171.225.130.45' as IPv4_string
SELECT
hex(IPv4StringToNum(IPv4_string)),
hex(toIPv4(IPv4_string))
```
2020-03-20 10:10:48 +00:00
``` text
2019-05-06 17:33:14 +00:00
┌─hex(IPv4StringToNum(IPv4_string))─┬─hex(toIPv4(IPv4_string))─┐
│ ABE1822D │ ABE1822D │
└───────────────────────────────────┴──────────────────────────┘
```
2022-06-02 10:55:18 +00:00
## toIPv4OrDefault(string)
2022-04-29 11:33:51 +00:00
Same as `toIPv4` , but if the IPv4 address has an invalid format, it returns 0.
2022-06-02 10:55:18 +00:00
## toIPv4OrNull(string)
2022-04-29 11:33:51 +00:00
Same as `toIPv4` , but if the IPv4 address has an invalid format, it returns null.
2022-06-02 10:55:18 +00:00
## toIPv6
2019-05-06 17:33:14 +00:00
2021-03-05 14:50:43 +00:00
Converts a string form of IPv6 address to [IPv6 ](../../sql-reference/data-types/domains/ipv6.md ) type. If the IPv6 address has an invalid format, returns an empty value.
Similar to [IPv6StringToNum ](#ipv6stringtonums ) function, which converts IPv6 address to binary format.
2019-05-06 17:33:14 +00:00
2021-03-05 14:50:43 +00:00
If the input string contains a valid IPv4 address, then the IPv6 equivalent of the IPv4 address is returned.
2019-05-06 17:33:14 +00:00
2021-03-05 14:50:43 +00:00
**Syntax**
```sql
toIPv6(string)
2019-05-06 17:33:14 +00:00
```
2021-03-05 14:50:43 +00:00
**Argument**
- `string` — IP address. [String ](../../sql-reference/data-types/string.md )
**Returned value**
2021-07-29 15:20:55 +00:00
- IP address.
2021-03-05 14:50:43 +00:00
Type: [IPv6 ](../../sql-reference/data-types/domains/ipv6.md ).
**Examples**
Query:
2020-03-20 10:10:48 +00:00
``` sql
2021-03-05 14:50:43 +00:00
WITH '2001:438:ffff::407d:1bc1' AS IPv6_string
2019-05-06 17:33:14 +00:00
SELECT
hex(IPv6StringToNum(IPv6_string)),
2021-03-05 14:50:43 +00:00
hex(toIPv6(IPv6_string));
2019-05-06 17:33:14 +00:00
```
2021-03-05 14:50:43 +00:00
Result:
2020-03-20 10:10:48 +00:00
``` text
2019-05-06 17:33:14 +00:00
┌─hex(IPv6StringToNum(IPv6_string))─┬─hex(toIPv6(IPv6_string))─────────┐
│ 20010438FFFF000000000000407D1BC1 │ 20010438FFFF000000000000407D1BC1 │
└───────────────────────────────────┴──────────────────────────────────┘
```
2019-04-24 06:20:02 +00:00
2021-03-05 14:50:43 +00:00
Query:
2021-01-26 03:04:08 +00:00
``` sql
2021-03-05 14:50:43 +00:00
SELECT toIPv6('127.0.0.1');
2021-01-26 03:04:08 +00:00
```
2021-03-05 14:50:43 +00:00
Result:
2021-01-26 03:04:08 +00:00
``` text
┌─toIPv6('127.0.0.1')─┐
│ ::ffff:127.0.0.1 │
└─────────────────────┘
```
2021-01-23 06:30:31 +00:00
2022-06-02 10:55:18 +00:00
## IPv6StringToNumOrDefault(s)
2022-04-29 11:33:51 +00:00
Same as `toIPv6` , but if the IPv6 address has an invalid format, it returns 0.
2022-06-02 10:55:18 +00:00
## IPv6StringToNumOrNull(s)
2022-04-29 11:33:51 +00:00
Same as `toIPv6` , but if the IPv6 address has an invalid format, it returns null.
2022-06-02 10:55:18 +00:00
## isIPv4String
2021-01-23 06:30:31 +00:00
2021-02-12 13:52:33 +00:00
Determines whether the input string is an IPv4 address or not. If `string` is IPv6 address returns `0` .
2021-01-23 06:30:31 +00:00
2021-02-04 15:31:00 +00:00
**Syntax**
```sql
isIPv4String(string)
2021-01-23 17:37:12 +00:00
```
2021-01-23 06:30:31 +00:00
2021-02-15 21:22:10 +00:00
**Arguments**
2021-02-04 15:31:00 +00:00
2021-02-06 10:12:17 +00:00
- `string` — IP address. [String ](../../sql-reference/data-types/string.md ).
2021-02-04 15:31:00 +00:00
**Returned value**
2021-02-12 13:52:33 +00:00
- `1` if `string` is IPv4 address, `0` otherwise.
2021-02-04 15:31:00 +00:00
Type: [UInt8 ](../../sql-reference/data-types/int-uint.md ).
**Examples**
Query:
```sql
2021-03-13 18:18:45 +00:00
SELECT addr, isIPv4String(addr) FROM ( SELECT ['0.0.0.0', '127.0.0.1', '::ffff:127.0.0.1'] AS addr ) ARRAY JOIN addr;
2021-02-04 15:31:00 +00:00
```
Result:
2021-01-23 17:37:12 +00:00
``` text
2021-02-12 13:52:33 +00:00
┌─addr─────────────┬─isIPv4String(addr)─┐
│ 0.0.0.0 │ 1 │
│ 127.0.0.1 │ 1 │
│ ::ffff:127.0.0.1 │ 0 │
└──────────────────┴────────────────────┘
2021-01-23 06:30:31 +00:00
```
2022-06-02 10:55:18 +00:00
## isIPv6String
2021-01-23 06:30:31 +00:00
2021-02-12 13:52:33 +00:00
Determines whether the input string is an IPv6 address or not. If `string` is IPv4 address returns `0` .
2021-02-04 15:31:00 +00:00
**Syntax**
```sql
isIPv6String(string)
```
2021-02-15 21:22:10 +00:00
**Arguments**
2021-02-04 15:31:00 +00:00
2021-02-06 10:12:17 +00:00
- `string` — IP address. [String ](../../sql-reference/data-types/string.md ).
2021-02-04 15:31:00 +00:00
**Returned value**
2021-02-12 13:52:33 +00:00
- `1` if `string` is IPv6 address, `0` otherwise.
2021-02-04 15:31:00 +00:00
Type: [UInt8 ](../../sql-reference/data-types/int-uint.md ).
**Examples**
Query:
2021-01-23 06:30:31 +00:00
``` sql
2021-03-13 18:18:45 +00:00
SELECT addr, isIPv6String(addr) FROM ( SELECT ['::', '1111::ffff', '::ffff:127.0.0.1', '127.0.0.1'] AS addr ) ARRAY JOIN addr;
2021-01-23 17:37:12 +00:00
```
2021-01-23 06:30:31 +00:00
2021-02-04 15:31:00 +00:00
Result:
2021-01-23 17:37:12 +00:00
``` text
2021-02-12 13:52:33 +00:00
┌─addr─────────────┬─isIPv6String(addr)─┐
│ :: │ 1 │
│ 1111::ffff │ 1 │
│ ::ffff:127.0.0.1 │ 1 │
│ 127.0.0.1 │ 0 │
└──────────────────┴────────────────────┘
2021-01-23 06:30:31 +00:00
```
2022-06-02 10:55:18 +00:00
## isIPAddressInRange
2021-02-17 08:57:48 +00:00
Determines if an IP address is contained in a network represented in the [CIDR ](https://en.wikipedia.org/wiki/Classless_Inter-Domain_Routing ) notation. Returns `1` if true, or `0` otherwise.
**Syntax**
``` sql
2021-03-29 10:43:21 +00:00
isIPAddressInRange(address, prefix)
2021-02-17 08:57:48 +00:00
```
2021-03-29 10:43:21 +00:00
This function accepts both IPv4 and IPv6 addresses (and networks) represented as strings. It returns `0` if the IP version of the address and the CIDR don't match.
2021-02-17 08:57:48 +00:00
2021-03-29 10:43:21 +00:00
**Arguments**
2021-02-17 08:57:48 +00:00
- `address` — An IPv4 or IPv6 address. [String ](../../sql-reference/data-types/string.md ).
- `prefix` — An IPv4 or IPv6 network prefix in CIDR. [String ](../../sql-reference/data-types/string.md ).
**Returned value**
- `1` or `0` .
Type: [UInt8 ](../../sql-reference/data-types/int-uint.md ).
**Example**
Query:
``` sql
2021-05-03 20:44:46 +00:00
SELECT isIPAddressInRange('127.0.0.1', '127.0.0.0/8');
2021-02-17 08:57:48 +00:00
```
Result:
``` text
2021-03-29 10:43:21 +00:00
┌─isIPAddressInRange('127.0.0.1', '127.0.0.0/8')─┐
│ 1 │
└────────────────────────────────────────────────┘
2021-02-17 08:57:48 +00:00
```
Query:
``` sql
2021-05-03 20:44:46 +00:00
SELECT isIPAddressInRange('127.0.0.1', 'ffff::/16');
2021-02-17 08:57:48 +00:00
```
Result:
``` text
2021-03-29 10:43:21 +00:00
┌─isIPAddressInRange('127.0.0.1', 'ffff::/16')─┐
│ 0 │
└──────────────────────────────────────────────┘
2021-02-17 08:57:48 +00:00
```
2022-05-09 16:03:10 +00:00
Query:
``` sql
SELECT isIPAddressInRange('::ffff:192.168.0.1', '::ffff:192.168.0.4/128');
```
Result:
``` text
┌─isIPAddressInRange('::ffff:192.168.0.1', '::ffff:192.168.0.4/128')─┐
│ 0 │
└────────────────────────────────────────────────────────────────────┘
```