Details
-
Task
-
Status: Closed (View Workflow)
-
Major
-
Resolution: Fixed
-
None
Description
Original task description
MariaDB will support the data type to store IPv6 addresses in table columns.
IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses
The objects of the IPv6 type can be used in any context where other MySQL data types are used.
All comparison operators over operands of this data type will be supported.
Also the basic function specific for this type will be supported.
The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'.
Implementation details
The new data type will work as follows:
General information
- The data type name is INET6
CREATE TABLE t1 (a INET6);
- Values are stored as a 16-byte fixed length binary string, with most significant byte first.
- Storage engines see INET6 as BINARY(16).
- Clients see INET6 as CHAR(39) and get text representation on retrieval.
Inserting values to INET6 columns
- Values can be inserted using short text address notation, according to RFC-5952:
INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329');
or long text address notation:
INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329');
or 16-byte binary string notation:
INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329);
INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329'));
- INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations:
INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped
INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible
The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6.
When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes:
CREATE OR REPLACE TABLE t1 (a INET6);
INSERT INTO t1 VALUES ('::ffff:192.0.2.128');
SELECT * FROM t1;
SELECT HEX(a) FROM t1;
+----------------------------------+
| HEX(a) |
+----------------------------------+
| 00000000000000000000FFFFC0000280 |
+----------------------------------+
Retrieving values from INET6 columns
- On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952:
SELECT a FROM t1;
+------------------------+
| a |
+------------------------+
| 2001:db8::ff00:42:8329 |
+------------------------+
i.e. with all leading zeroes in each group removed and with consequent zero groups compressed.
- There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation.
CAST from and to INET6
- CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood.
- CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16.
- CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied.
- CAST from INET6 to CHAR returns short text address notation.
- CAST from INET6 to BINARY returns its 16-byte binary string representation.
- CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error:
SELECT CAST(a AS DECIMAL) FROM t1;
ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast'
Comparing INET6 values
An INET6 expression can be compared to:
- another INET6 expression
CREATE OR REPLACE TABLE t1 (a INET6);
CREATE OR REPLACE TABLE t2 (a INET6);
INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329');
INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329');
SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a;
+------------------------+
| a |
+------------------------+
| 2001:db8::ff00:42:8329 |
+------------------------+
- to a character string expression with a text (short or long) address representation:
CREATE OR REPLACE TABLE t1 (a INET6);
INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329');
SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329';
+------------------------+
| a |
+------------------------+
| 2001:db8::ff00:42:8329 |
+------------------------+
- or to a 16-byte binary string expression:
CREATE OR REPLACE TABLE t1 (a INET6);
INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329');
SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329';
+------------------------+
| a |
+------------------------+
| 2001:db8::ff00:42:8329 |
+------------------------+
An attempt to compare INET6 to an expression of other data types returns an error:
SELECT * FROM t1 WHERE a=1; |
ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '='
|
Mixing INET6 values for result
An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with:
- another INET6 expression. The result data type is INET6.
CREATE OR REPLACE TABLE t1 (a INET6, b INET6);
INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329');
SELECT a FROM t1 UNION SELECT b FROM t1;
+------------------------+
| a |
+------------------------+
| NULL |
| 2001:db8::ff00:42:8329 |
+------------------------+
SELECT COALESCE(a, b) FROM t1;
+------------------------+
| COALESCE(a, b) |
+------------------------+
| 2001:db8::ff00:42:8329 |
+------------------------+
- a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result.
CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64));
INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328');
INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage');
SELECT COALESCE(a,b) FROM t1;
SHOW WARNINGS;
+------------------------+
| COALESCE(a,b) |
+------------------------+
| 2001:db8::ff00:42:8328 |
| NULL |
+------------------------+
2 rows in set, 1 warning (0.001 sec)
+---------+------+---------------------------------------------------------+
| Level | Code | Message |
+---------+------+---------------------------------------------------------+
| Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' |
+---------+------+---------------------------------------------------------+
- a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result.
CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16));
INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF));
INSERT INTO t1 VALUES (NULL,0x00/*garbage*/);
SELECT COALESCE(a,b) FROM t1;
SHOW WARNINGS;
+---------------+
| COALESCE(a,b) |
+---------------+
| ffff::ffff |
| NULL |
+---------------+
2 rows in set, 1 warning (0.001 sec)
+---------+------+-------------------------------+
| Level | Code | Message |
+---------+------+-------------------------------+
| Warning | 1292 | Incorrect inet6 value: '\x00' |
+---------+------+-------------------------------+
Attempts to mix INET6 for result with other data types return errors:
SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; |
ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION'
|
Mixing INET6 values for LEAST() and GREATEST()
Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph.
Functions and operators
- HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string:
SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6));
+----------------------------------------------+
| HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) |
+----------------------------------------------+
| 20010DB8000000000000FF0000428329 |
+----------------------------------------------+
- Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future.
- Function INET6_ATON() now understands INET6 values as an argument:
CREATE OR REPLACE TABLE t1 (a INET6);
INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329');
SELECT a, HEX(INET6_ATON(a)) FROM t1;
+------------------------+----------------------------------+
| a | HEX(INET6_ATON(a)) |
+------------------------+----------------------------------+
| 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 |
+------------------------+----------------------------------+
- 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from
IS_IPV4_COMPAT(a BINARY(16))
IS_IPV4_MAPPED(a BINARY(16))
to
IS_IPV4_COMPAT(a INET6)
IS_IPV4_MAPPED(a INET6)
Example:
CREATE OR REPLACE TABLE t1 (a INET6);
INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329');
INSERT INTO t1 VALUES ('::ffff:192.168.0.1');
INSERT INTO t1 VALUES ('::192.168.0.1');
SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1;
+------------------------+-------------------+-------------------+
| a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) |
+------------------------+-------------------+-------------------+
| 2001:db8::ff00:42:8329 | 0 | 0 |
| ::ffff:192.168.0.1 | 1 | 0 |
| ::192.168.0.1 | 0 | 1 |
+------------------------+-------------------+-------------------+
When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation.
CREATE OR REPLACE TABLE t1 (
a INET6,
b VARCHAR(39) DEFAULT a
);
INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1');
SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1;
+--------------------+-------------------+--------------------+-------------------+
| a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) |
+--------------------+-------------------+--------------------+-------------------+
| ffff::ffff | 0 | ffff::ffff | 0 |
| ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 |
+--------------------+-------------------+--------------------+-------------------+
CREATE OR REPLACE TABLE t1 (
a INET6,
b BINARY(16) DEFAULT UNHEX(HEX(a))
);
INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1');
SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1;
+--------------------+-------------------+----------------------------------+-------------------+
| a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) |
+--------------------+-------------------+----------------------------------+-------------------+
| ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 |
| ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 |
+--------------------+-------------------+----------------------------------+-------------------+
INET6 and prepared statement parameters
INET6 understands both text and binary(16) address representation in prepared statement parameters (PREPARE..EXECUTE and EXECUTE IMMEDIATE statements).
CREATE OR REPLACE TABLE t1 (a INET6); |
EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING 'ffff::fffe'; |
EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING X'FFFF000000000000000000000000FFFF'; |
SELECT * FROM t1; |
+------------+
|
| a |
|
+------------+
|
| ffff::fffe |
|
| ffff::ffff |
|
+------------+
|
EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING 'ffff::fffe'; |
+------------+
|
| a |
|
+------------+
|
| ffff::fffe |
|
+------------+
|
EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING X'FFFF000000000000000000000000FFFF'; |
+------------+
|
| a |
|
+------------+
|
| ffff::ffff |
|
+------------+
|
Migration from BINARY(16) to INET6
Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data:
CREATE OR REPLACE TABLE t1 (a BINARY(16)); |
INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); |
SELECT INET6_NTOA(a) FROM t1; |
+---------------+
|
| INET6_NTOA(a) |
|
+---------------+
|
| ffff::ffff |
|
+---------------+
|
In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly:
ALTER TABLE t1 MODIFY a INET6; |
INSERT INTO t1 VALUES ('ffff::fffe'); |
SELECT * FROM t1; |
+------------+
|
| a |
|
+------------+
|
| ffff::ffff |
|
| ffff::fffe |
|
+------------+
|
Migration from INET6 to BINARY(16)
It is possible to convert INET6 columns to BINARY(16) and continue using the data in combination with INET6_NTOA() and INET6_ATON().
CREATE OR REPLACE TABLE t1 (a INET6); |
INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); |
INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); |
INSERT INTO t1 VALUES ('::192.168.0.1'); |
ALTER TABLE t1 MODIFY a BINARY(16); |
SELECT INET6_NTOA(a) FROM t1; |
+------------------------+
|
| INET6_NTOA(a) |
|
+------------------------+
|
| 2001:db8::ff00:42:8329 |
|
| ::ffff:192.168.0.1 |
|
| ::192.168.0.1 |
|
+------------------------+
|
Attachments
Issue Links
- causes
-
MDEV-20781 Document INET6 (MDEV-274)
-
- Closed
-
- is blocked by
-
MDEV-4912 Data type plugin API version 1
-
- Closed
-
-
MDEV-17995 INET6_NTOA(ucs2_input) erroneously returns NULL
-
- Closed
-
-
MDEV-18010 Add classes Inet4 and Inet6
-
- Closed
-
-
MDEV-19184 Crash in IS_IPV6(_ucs2 0x0031)
-
- Closed
-
-
MDEV-19994 Add class Function_collection
-
- Closed
-
-
MDEV-20760 Add Type_handler::KEY_pack_flags()
-
- Closed
-
-
MDEV-20764 Add MariaDB_FUNCTION_COLLECTION_PLUGIN
-
- Closed
-
-
MDEV-20768 Turn INET functions into a function collection plugin
-
- Closed
-
-
MDEV-20837 Add MariaDB_FUNCTION_PLUGIN
-
- Closed
-
- relates to
-
MDEV-20783 INET6 cannot be converted to BINARY(16) (requires clarification in documentation)
-
- Closed
-
-
MDEV-20785 Converting INET6 to CHAR(39) produces garbage without a warning
-
- Closed
-
-
MDEV-20800 Server crashes in Field_inet6::store_warning upon updating table statistics
-
- Closed
-
-
MDEV-20806 Federated does not work with INET6, returns NULL with warning ER_TRUNCATED_WRONG_VALUE
-
- Closed
-
-
MDEV-20808 CAST from INET6 to FLOAT does not produce an error
-
- Closed
-
-
MDEV-20809 EXTRACT from INET6 value does not produce any warnings
-
- Closed
-
-
MDEV-20826 Wrong result of MIN(inet6) with GROUP BY
-
- Closed
-
-
MDEV-20831 Table partitioned by LIST/RANGE COLUMNS(inet6) can be created, but not inserted into
-
- Closed
-
-
MDEV-20844 RBR from binary(16) to inet6 fails with error 171: The event was corrupt, leading to illegal data being read
-
- Closed
-
-
MDEV-21764 CONNECT table with INET6 field produces warnings upon SELECT
-
- Closed
-
-
MDEV-21765 Possibly inconsistent behavior of BIT_xx functions with INET6 field
-
- Closed
-
-
MDEV-22509 Server crashes in Field_inet6::store_inet6_null_with_warn / Field::maybe_null
-
- Closed
-
-
MDEV-23287 INET4 data type
-
- Closed
-
-
MDEV-4051 INET6_ATON() and INET6_NTOA()
-
- Closed
-
-
MDEV-7676 Update site information on IPv6 support / status
-
- Closed
-
-
MDEV-20790 CSV table with INET6 can be created and inserted into, but cannot be read from
-
- Closed
-
-
MDEV-20791 In table partitioned by INET6 all values go into the same partition
-
- Open
-
-
MDEV-20798 Conversion from INET6 to other types performed without errors or warnings
-
- Closed
-
Activity
Field | Original Value | New Value |
---|---|---|
Description |
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any sub-sequence of 4 hexadecimal '0:0:0:0' is represented by one hexadecimal '0'. |
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. |
Fix Version/s | 10.0.0 [ 10000 ] |
Status | Open [ 1 ] | In Progress [ 3 ] |
Status | In Progress [ 3 ] | Open [ 1 ] |
Fix Version/s | 10.0.1 [ 11400 ] | |
Fix Version/s | 10.0.0 [ 10000 ] |
Assignee | Igor Babaev [ igor ] | Vladislav Vaintroub [ wlad ] |
Fix Version/s | 10.0.2 [ 11900 ] | |
Fix Version/s | 10.0.1 [ 11400 ] |
Fix Version/s | 10.0.3 [ 12900 ] | |
Fix Version/s | 10.0.2 [ 11900 ] |
Fix Version/s | 10.0.4 [ 13101 ] | |
Fix Version/s | 10.0.3 [ 12900 ] |
Priority | Major [ 3 ] | Minor [ 4 ] |
Fix Version/s | 10.0.5 [ 13201 ] | |
Fix Version/s | 10.0.4 [ 13101 ] |
Fix Version/s | 10.0.6 [ 13202 ] | |
Fix Version/s | 10.0.5 [ 13201 ] |
Fix Version/s | 10.0.7 [ 14100 ] | |
Fix Version/s | 10.0.6 [ 13202 ] |
Fix Version/s | 10.0.8 [ 14200 ] | |
Fix Version/s | 10.0.7 [ 14100 ] |
Assignee | Vladislav Vaintroub [ wlad ] |
Fix Version/s | 10.1.0 [ 12200 ] | |
Fix Version/s | 10.0.8 [ 14200 ] |
Priority | Minor [ 4 ] | Major [ 3 ] |
Priority | Major [ 3 ] | Critical [ 2 ] |
Assignee | Alexander Barkov [ bar ] |
Workflow | defaullt [ 11810 ] | MariaDB v2 [ 43835 ] |
Fix Version/s | 10.1 [ 16100 ] | |
Fix Version/s | 10.1.0 [ 12200 ] |
Status | Open [ 1 ] | In Progress [ 3 ] |
Assignee | Alexander Barkov [ bar ] | Sergei Golubchik [ serg ] |
Status | In Progress [ 3 ] | In Review [ 10002 ] |
Assignee | Sergei Golubchik [ serg ] | Alexander Barkov [ bar ] |
Status | In Review [ 10002 ] | Stalled [ 10000 ] |
Status | Stalled [ 10000 ] | In Progress [ 3 ] |
Workflow | MariaDB v2 [ 43835 ] | MariaDB v3 [ 67325 ] |
Fix Version/s | 10.2 [ 14601 ] | |
Fix Version/s | 10.1 [ 16100 ] |
Status | In Progress [ 3 ] | Stalled [ 10000 ] |
Priority | Critical [ 2 ] | Major [ 3 ] |
Fix Version/s | 10.2 [ 14601 ] |
Fix Version/s | 10.3 [ 22126 ] |
Component/s | Data types [ 13906 ] |
Fix Version/s | 10.3 [ 22126 ] |
Link |
This issue is blocked by |
Link |
This issue is blocked by |
Link | This issue is blocked by MDEV-19180 [ MDEV-19180 ] |
Link |
This issue is blocked by |
Link |
This issue is blocked by |
Link |
This issue is blocked by |
Link |
This issue is blocked by |
Description |
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The INET6 data type will work as follows: - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0xFFFF000000000000000000000000FFFF); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, its converted to NULL or to '::' depending on context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The INET6 data type will work as follows: - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0xFFFF000000000000000000000000FFFF); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, its converted to NULL or to '::' depending on context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The INET6 data type will work as follows: - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, its converted to NULL or to '::' depending on context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The INET6 data type will work as follows: - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, its converted to NULL or to '::' depending on context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, its converted to NULL or to '::' depending on context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, its converted to NULL or to '::' depending on context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, its converted to NULL or to '::' depending on context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, its converted to NULL or to '::' depending on context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: INSERT INTO t1 VALUES ('::ffff:192.0.2.128'/*mapped*/); INSERT INTO t1 VALUES ('::192.0.2.128'/*compatible*/); - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: INSERT INTO t1 VALUES ('::ffff:192.0.2.128'/*mapped*/); INSERT INTO t1 VALUES ('::192.0.2.128'/*compatible*/); - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} Note, the IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} Note, the IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} Note, the IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} Note, the IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} Note, the IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} Note, the IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and consequent zero groups replaced to '::'. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using compact text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the compact text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in compact or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns compact text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (compact or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (compact or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in short or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (short or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in short or long text notation. NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (short or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (short or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - INET6 can be compared to INET6, to a character string with a text (short or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values - INET6 can be compared to INET6, to a character string with a text (short or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values - INET6 can be compared to INET6, to a character string with a text (short or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values - INET6 can be compared to INET6, to a character string with a text (short or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values - INET6 can be compared to INET6, to a character string with a text (short or long) representation, or to a 16-byte binary string. - An attempt to compare INET6 to another data type returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6. Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6. Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result - INET6 can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): -- With INET6 -- With a character string in text (short or long) address representation. If the string format is not understood, it's converted to NULL or to '::' depending on the context. -- With a 16-byte binary string. If the binary string length is not 16, it's converted to NULL or to '::' depending on the context. - An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): - With another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - With a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8327 | | 2001:db8::ff00:42:8329 | | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 4 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - With a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc): - With another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - With a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8327 | | 2001:db8::ff00:42:8329 | | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 4 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - With a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8327 | | 2001:db8::ff00:42:8329 | | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 4 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8327 | | 2001:db8::ff00:42:8329 | | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 4 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() - Aggregation for LEAST() and GREATEST() uses the same rules with aggregation for result. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when both mixing for comparison and mixing for result is involved, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when both mixing for comparison and mixing for result is involved, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
issue.field.resolutiondate | 2019-10-09 08:33:39.0 | 2019-10-09 08:33:39.515 |
Fix Version/s | 10.5.0 [ 23709 ] | |
Resolution | Fixed [ 1 ] | |
Status | Stalled [ 10000 ] | Closed [ 6 ] |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or a 16-byte binary string: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - Functions IS_IPV4_MAPPED() and IS_IPV4_COMPAT() now understand INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Link |
This issue relates to |
Link |
This issue relates to |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte array as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} An attempt to mix INET6 for result with other data types return an error: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempt to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempt to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempts to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempts to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempts to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. INET6 and prepared statement parameters INET6 understands both text and binary(16) address representation in prepared statement parameters. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING 'ffff::fffe'; EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING X'FFFF000000000000000000000000FFFF'; SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | | ffff::ffff | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING 'ffff::fffe'; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING X'FFFF000000000000000000000000FFFF'; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | +------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempts to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. INET6 and prepared statement parameters INET6 understands both text and binary(16) address representation in prepared statement parameters. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING 'ffff::fffe'; EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING X'FFFF000000000000000000000000FFFF'; SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | | ffff::ffff | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING 'ffff::fffe'; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING X'FFFF000000000000000000000000FFFF'; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | +------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempts to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. INET6 and prepared statement parameters INET6 understands both text and binary(16) address representation in prepared statement parameters (PREPARE..EXECUTE and EXECUTE IMMEDIATE statements). {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING 'ffff::fffe'; EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING X'FFFF000000000000000000000000FFFF'; SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | | ffff::ffff | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING 'ffff::fffe'; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING X'FFFF000000000000000000000000FFFF'; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | +------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Link | This issue relates to MDEV-20791 [ MDEV-20791 ] |
Link |
This issue relates to |
Link |
This issue relates to |
Link |
This issue relates to |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempts to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. INET6 and prepared statement parameters INET6 understands both text and binary(16) address representation in prepared statement parameters (PREPARE..EXECUTE and EXECUTE IMMEDIATE statements). {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING 'ffff::fffe'; EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING X'FFFF000000000000000000000000FFFF'; SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | | ffff::ffff | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING 'ffff::fffe'; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING X'FFFF000000000000000000000000FFFF'; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | +------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to BINARY returns its 16-byte binary string representation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempts to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. INET6 and prepared statement parameters INET6 understands both text and binary(16) address representation in prepared statement parameters (PREPARE..EXECUTE and EXECUTE IMMEDIATE statements). {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING 'ffff::fffe'; EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING X'FFFF000000000000000000000000FFFF'; SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | | ffff::ffff | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING 'ffff::fffe'; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING X'FFFF000000000000000000000000FFFF'; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | +------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
Description |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to BINARY returns its 16-byte binary string representation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempts to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. INET6 and prepared statement parameters INET6 understands both text and binary(16) address representation in prepared statement parameters (PREPARE..EXECUTE and EXECUTE IMMEDIATE statements). {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING 'ffff::fffe'; EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING X'FFFF000000000000000000000000FFFF'; SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | | ffff::ffff | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING 'ffff::fffe'; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING X'FFFF000000000000000000000000FFFF'; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | +------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} |
h2. Original task description
MariaDB will support the data type to store IPv6 addresses in table columns. IPv4 addresses will be also supported by this type assuming conventional mapping of IPv4 addresses into IPv6 addresses The objects of the IPv6 type can be used in any context where other MySQL data types are used. All comparison operators over operands of this data type will be supported. Also the basic function specific for this type will be supported. The internal representation of the values of this type will support the conventional compression used for IPv6 addresses when any group of 4 hexadecimal '0000' is represented by one hexadecimal '0'. h2. Implementation details The new data type will work as follows: h2. General information - The data type name is INET6 {code:sql} CREATE TABLE t1 (a INET6); {code} - Values are stored as a 16-byte fixed length binary string, with most significant byte first. - Storage engines see INET6 as BINARY(16). - Clients see INET6 as CHAR(39) and get text representation on retrieval. h2. Inserting values to INET6 columns - Values can be inserted using short text address notation, according to RFC-5952: {code:sql} INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); {code} or long text address notation: {code:sql} INSERT INTO t1 VALUES ('2001:0db8:0000:0000:0000:ff00:0042:8329'); {code} or 16-byte binary string notation: {code:sql} INSERT INTO t1 VALUES (0x20010DB8000000000000FF0000428329); INSERT INTO t1 VALUES (UNHEX('20010DB8000000000000FF0000428329')); {code} - INET6 can also store IPv4 addresses, using IPv4-mapped and IPv4-compatible notations: {code:sql} INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); -- mapped INSERT INTO t1 VALUES ('::192.0.2.128'); -- compatible {code} {quote} The IPv4-compatible notation is considered as deprecated. It is supported for compatibility with the INET6_ATON() function, which also understands this format. It's recommended to use the mapped format to store IPv4 addresses in INET6. {quote} {quote} When an IPv4 mapped (or compatible) value is stored in INET6, it still occupies 16 bytes: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('::ffff:192.0.2.128'); SELECT * FROM t1; SELECT HEX(a) FROM t1; {code} {noformat} +----------------------------------+ | HEX(a) | +----------------------------------+ | 00000000000000000000FFFFC0000280 | +----------------------------------+ {noformat} {quote} h2. Retrieving values from INET6 columns - On retrieval, in the client-server text protocol, INET6 values are converted to the short text representation, according to RFC-5952: {code:sql} SELECT a FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} i.e. with all leading zeroes in each group removed and with consequent zero groups compressed. - There is no a way to retrieve INET6 value using long text representation. One can create a simple stored function for this purpose. If we have user requests, we can later add a built-in function to convert INET6 values to long text representation. h2. CAST from and to INET6 - CAST from a character string to INET6 understands addresses in short or long text notation (including IPv4 mapped and compatible addresses). NULL is returned if the format is not understood. - CAST from a binary string to INET6 requires a 16-byte string as an argument. NULL is returned if the argument length is not equalt to 16. - CAST from other data types to INET6 first converts data to a character string, then CAST from character string to INET6 is applied. - CAST from INET6 to CHAR returns short text address notation. - CAST from INET6 to BINARY returns its 16-byte binary string representation. - CAST from INET6 to data types other than CHAR (e.g. SIGNED, UNSIGNED, TIME, etc) returns an error: {code:sql} SELECT CAST(a AS DECIMAL) FROM t1; {code} {noformat} ERROR 4079 (HY000): Illegal parameter data type inet6 for operation 'decimal_typecast' {noformat} h2. Comparing INET6 values An INET6 expression can be compared to: - another INET6 expression {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); CREATE OR REPLACE TABLE t2 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8328'),('2001:db8::ff00:42:8329'); INSERT INTO t2 VALUES ('2001:db8::ff00:42:832a'),('2001:db8::ff00:42:8329'); SELECT t1.* FROM t1,t2 WHERE t1.a=t2.a; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - to a character string expression with a text (short or long) address representation: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a='2001:db8::ff00:42:8329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - or to a 16-byte binary string expression: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT * FROM t1 WHERE a=X'20010DB8000000000000FF0000428329'; {code} {noformat} +------------------------+ | a | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} An attempt to compare INET6 to an expression of other data types returns an error: {code:sql} SELECT * FROM t1 WHERE a=1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation '=' {noformat} h2. Mixing INET6 values for result An INET6 expression can be mixed for result (i.e. UNION, CASE..THEN, COALESCE etc) with: - another INET6 expression. The result data type is INET6. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b INET6); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8329'); SELECT a FROM t1 UNION SELECT b FROM t1; {code} {noformat} +------------------------+ | a | +------------------------+ | NULL | | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} {code:sql} SELECT COALESCE(a, b) FROM t1; {code} {noformat} +------------------------+ | COALESCE(a, b) | +------------------------+ | 2001:db8::ff00:42:8329 | +------------------------+ {noformat} - a character string in text (short or long) address representation. The result data type is INET6. The character string counterpart is automatically converted to INET6. If the string format is not understood, it's converted with a warning to either NULL or to '::', depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARCHAR(64)); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:8328'); INSERT INTO t1 VALUES (NULL,'2001:db8::ff00:42:832a garbage'); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +------------------------+ | COALESCE(a,b) | +------------------------+ | 2001:db8::ff00:42:8328 | | NULL | +------------------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+---------------------------------------------------------+ | Level | Code | Message | +---------+------+---------------------------------------------------------+ | Warning | 1292 | Incorrect inet6 value: '2001:db8::ff00:42:832a garbage' | +---------+------+---------------------------------------------------------+ {noformat} - a 16-byte binary string. The result data type is INET6. The binary string counterpart is automatically converted to INET6. If the length of the binary string is not equal to 16, it's converted with a warning to NULL or to '::' depending on the NULL-ability of the result. {code:sql} CREATE OR REPLACE TABLE t1 (a INET6, b VARBINARY(16)); INSERT INTO t1 VALUES (NULL,CONCAT(0xFFFF,REPEAT(0x0000,6),0xFFFF)); INSERT INTO t1 VALUES (NULL,0x00/*garbage*/); SELECT COALESCE(a,b) FROM t1; SHOW WARNINGS; {code} {noformat} +---------------+ | COALESCE(a,b) | +---------------+ | ffff::ffff | | NULL | +---------------+ 2 rows in set, 1 warning (0.001 sec) {noformat} {noformat} +---------+------+-------------------------------+ | Level | Code | Message | +---------+------+-------------------------------+ | Warning | 1292 | Incorrect inet6 value: '\x00' | +---------+------+-------------------------------+ {noformat} Attempts to mix INET6 for result with other data types return errors: {code:sql} SELECT CAST('ffff::ffff' AS INET6) UNION SELECT 1; {code} {noformat} ERROR 4078 (HY000): Illegal parameter data types inet6 and int for operation 'UNION' {noformat} h2. Mixing INET6 values for LEAST() and GREATEST() Mixing INET6 with other data types for LEAST() and GREATEST(), when mixing for comparison and mixing for result are involved at the same time, uses the same rules with mixing for result, described in the previous paragraph. h2. Functions and operators - HEX() with an INET6 argument returns hexadecimal representation of the underlying 16-byte binary string: {code:sql} SELECT HEX(CAST('2001:db8::ff00:42:8329' AS INET6)); {code} {noformat} +----------------------------------------------+ | HEX(CAST('2001:db8::ff00:42:8329' AS INET6)) | +----------------------------------------------+ | 20010DB8000000000000FF0000428329 | +----------------------------------------------+ {noformat} - Arithmetic operators (+,-,*,/,MOD,DIV) are not supported for INET6. This may change in the future. - Function INET6_ATON() now understands INET6 values as an argument: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); SELECT a, HEX(INET6_ATON(a)) FROM t1; {code} {noformat} +------------------------+----------------------------------+ | a | HEX(INET6_ATON(a)) | +------------------------+----------------------------------+ | 2001:db8::ff00:42:8329 | 20010DB8000000000000FF0000428329 | +------------------------+----------------------------------+ {noformat} - 10.5.0 changed prototypes of these SQL functions IS_IPV4_COMPAT() and IS_IPV4_MAPPED() from {code:sql} IS_IPV4_COMPAT(a BINARY(16)) IS_IPV4_MAPPED(a BINARY(16)) {code} to {code:sql} IS_IPV4_COMPAT(a INET6) IS_IPV4_MAPPED(a INET6) {code} Example: {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), IS_IPV4_COMPAT(a) FROM t1; {code} {noformat} +------------------------+-------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | IS_IPV4_COMPAT(a) | +------------------------+-------------------+-------------------+ | 2001:db8::ff00:42:8329 | 0 | 0 | | ::ffff:192.168.0.1 | 1 | 0 | | ::192.168.0.1 | 0 | 1 | +------------------------+-------------------+-------------------+ {noformat} When the argument is not INET6, automatic implicit CAST to INET6 is applied. As a consequence, IS_IPV4_COMPAT() and IS_IPV4_MAPPED() now understand arguments in both text representation and binary(16) representation. In versions before 10.5.0, these functions understood only binary(16) representation. {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b VARCHAR(39) DEFAULT a ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), b, IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+--------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | b | IS_IPV4_MAPPED(b) | +--------------------+-------------------+--------------------+-------------------+ | ffff::ffff | 0 | ffff::ffff | 0 | | ::ffff:192.168.0.1 | 1 | ::ffff:192.168.0.1 | 1 | +--------------------+-------------------+--------------------+-------------------+ {noformat} {code:sql} CREATE OR REPLACE TABLE t1 ( a INET6, b BINARY(16) DEFAULT UNHEX(HEX(a)) ); INSERT INTO t1 (a) VALUES ('ffff::ffff'),('::ffff:192.168.0.1'); SELECT a, IS_IPV4_MAPPED(a), HEX(b), IS_IPV4_MAPPED(b) FROM t1; {code} {noformat} +--------------------+-------------------+----------------------------------+-------------------+ | a | IS_IPV4_MAPPED(a) | HEX(b) | IS_IPV4_MAPPED(b) | +--------------------+-------------------+----------------------------------+-------------------+ | ffff::ffff | 0 | FFFF000000000000000000000000FFFF | 0 | | ::ffff:192.168.0.1 | 1 | 00000000000000000000FFFFC0A80001 | 1 | +--------------------+-------------------+----------------------------------+-------------------+ {noformat} h2. INET6 and prepared statement parameters INET6 understands both text and binary(16) address representation in prepared statement parameters (PREPARE..EXECUTE and EXECUTE IMMEDIATE statements). {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING 'ffff::fffe'; EXECUTE IMMEDIATE 'INSERT INTO t1 VALUES (?)' USING X'FFFF000000000000000000000000FFFF'; SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | | ffff::ffff | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING 'ffff::fffe'; {code} {noformat} +------------+ | a | +------------+ | ffff::fffe | +------------+ {noformat} {code:sql} EXECUTE IMMEDIATE 'SELECT * FROM t1 WHERE a=?' USING X'FFFF000000000000000000000000FFFF'; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | +------------+ {noformat} h2. Migration from BINARY(16) to INET6 Suppose, prior to 10.5.0, you have used BINARY(16) as a storage for IPv6 internet addresses, in combination with INET6_ATON() and INET6_NTOA() to respectively insert and retrieve data: {code:sql} CREATE OR REPLACE TABLE t1 (a BINARY(16)); INSERT INTO t1 VALUES (INET6_ATON('ffff::ffff')); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +---------------+ | INET6_NTOA(a) | +---------------+ | ffff::ffff | +---------------+ {noformat} In 10.5, you can alter BINARY(16) columns storing IPv6 addresses to INET6. After such ALTER there is no a need to use INET6_ATON() and INET6_NTOA(). Addresses can be inserted and retrieved directly: {code:sql} ALTER TABLE t1 MODIFY a INET6; INSERT INTO t1 VALUES ('ffff::fffe'); SELECT * FROM t1; {code} {noformat} +------------+ | a | +------------+ | ffff::ffff | | ffff::fffe | +------------+ {noformat} h2. Migration from INET6 to BINARY(16) It is possible to convert INET6 columns to BINARY(16) and continue using the data in combination with INET6_NTOA() and INET6_ATON(). {code:sql} CREATE OR REPLACE TABLE t1 (a INET6); INSERT INTO t1 VALUES ('2001:db8::ff00:42:8329'); INSERT INTO t1 VALUES ('::ffff:192.168.0.1'); INSERT INTO t1 VALUES ('::192.168.0.1'); ALTER TABLE t1 MODIFY a BINARY(16); SELECT INET6_NTOA(a) FROM t1; {code} {noformat} +------------------------+ | INET6_NTOA(a) | +------------------------+ | 2001:db8::ff00:42:8329 | | ::ffff:192.168.0.1 | | ::192.168.0.1 | +------------------------+ {noformat} |
Link |
This issue relates to |
Link |
This issue relates to |
Link |
This issue relates to |
Link |
This issue is blocked by |
Link |
This issue relates to |
Link |
This issue relates to |
Link |
This issue is blocked by |
Link |
This issue relates to |
Link |
This issue relates to |
Link |
This issue relates to |
Link | This issue is blocked by MDEV-19180 [ MDEV-19180 ] |
Link |
This issue relates to |
Link |
This issue causes |
Link |
This issue relates to |
Workflow | MariaDB v3 [ 67325 ] | MariaDB v4 [ 131929 ] |
Link | This issue relates to MENT-412 [ MENT-412 ] |
The IPV6 type should work as follows:
Example:
CREATE TABLE t1 (a ipv6);
insert into t1 values ("2001:0db8:0000:0000:0000:ff00:0042:8329"), ("2001:0db8::ff00:0042:8329");
select a, ipv6_compact(a) from t1;
a ipv6_compact(a) from t1;
"2001:0db8:0000:0000:0000:ff00:0042:8329" "2001:0db8::ff00:0042:8329"
"2001:0db8:0000:0000:0000:ff00:0042:8329" "2001:0db8::ff00:0042:8329"