Skip to content
Permalink
Browse files
MDEV-28918 Implicit cast from INET6 UNSIGNED works differently on UPD…
…ATE vs ALTER

Now INSERT, UPDATE, ALTER statements involving incompatible data type pairs, e.g.:

    UPDATE TABLE t1 SET col_inet6=col_int;
    INSERT INTO t1 (col_inet6) SELECT col_in FROM t2;
    ALTER TABLE t1 MODIFY col_inet6 INT;

consistently return an error at the statement preparation time:

    ERROR HY000: Illegal parameter data types inet6 and int for operation 'SET'

and abort the statement before starting interating rows.

This error is the same with what is raised for queries like:
    SELECT col_inet6 FROM t1 UNION SELECT col_int FROM t2;
    SELECT COALESCE(col_inet6, col_int) FROM t1;

Before this change the error was caught only during the execution time,
when a Field_xxx::store_xxx() was called for the very firts row.
The behavior was not consistent between various statements and could do different things:
- abort the statement
- set a column to the data type default value (e.g. '::' for INET6)
- set a column to NULL

A typical old error was:

    ERROR 22007: Incorrect inet6 value: '1' for column `test`.`t1`.`a` at row 1

EXCEPTION:

Note, there is an exception: a multi-row INSERT..VALUES, e.g.:
    INSERT INTO t1 (col_a,col_b) VALUES (a1,b1),(a2,b2);
checks assignment compability at the preparation time for the very first row only:
    (col_a,col_b) vs (a1,b1)

Other rows are still checked at the execution time and return the old warnings
or errors in case of a failure. This is done because catching all rows at the
preparation time would change behavior significantly. So it still works
according to the STRICT_XXX_TABLES sql_mode flags and the table transaction ability.

This is too late to change this behavior in 10.7.
There is no a firm decision yet if a multi-row INSERT..VALUES
behavior will change in later versions.
  • Loading branch information
abarkov committed Jun 27, 2022
1 parent 925999b commit 0bed4d7
Show file tree
Hide file tree
Showing 49 changed files with 2,805 additions and 120 deletions.
@@ -180,9 +180,9 @@ insert IGNORE into t1 (a) values ('Garbage');
drop table t1;

create table t1 (pk integer primary key auto_increment, fl geometry not null);
--error 1416
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
insert into t1 (fl) values (1);
--error 1416
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
insert into t1 (fl) values (1.11);
--error 1416
insert into t1 (fl) values ("qwerty");
@@ -0,0 +1,137 @@
--echo # Start of type_store_assignment_incompatible.inc

SET @source_type= (SELECT COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS
WHERE COLUMN_NAME='source'
AND TABLE_NAME='t1'
AND TABLE_SCHEMA='test');

SET @target_type= (SELECT COLUMN_TYPE FROM INFORMATION_SCHEMA.COLUMNS
WHERE COLUMN_NAME='target'
AND TABLE_NAME='t1'
AND TABLE_SCHEMA='test');

CREATE TABLE t2 LIKE t1;
ALTER TABLE t2 ADD id INT NOT NULL PRIMARY KEY FIRST;
INSERT INTO t2 VALUES (1,DEFAULT,DEFAULT);
SHOW CREATE TABLE t2;

#
# Single row INSERT..VALUES
#

CREATE TABLE t3 LIKE t2;
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
INSERT INTO t3 VALUES
(1,
(SELECT source FROM t2 ORDER BY id LIMIT 1),
(SELECT source FROM t2 ORDER BY id LIMIT 1));
DROP TABLE t3;

#
# Multi-row INSERT..VALUES
#

# INSERT .. VALUES checks assignment compatibility for the first row only.
# Here the first row is compatible, so no error happens.
# The second row is not compatible. It works according to the
# current sql_mode and the table transaction ability, so it can:
# (a) either raise a warning
# (b) or escalate a warning to an error and abort on the current row
# (c) or escalate a warning to an error and rollback
# Here we test (a) and (b).

SET sql_mode='';
CREATE TABLE t3 LIKE t2;
ALTER TABLE t3 ENGINE=MyISAM;
EXECUTE IMMEDIATE
CONCAT('CREATE VIEW v3 AS SELECT id,',
IF(@target_type='geometry','AsText(target)','target'), ' AS target,',
IF(@source_type='geometry','AsText(source)','source'), ' AS source ',
' FROM t3');

--error 0,ER_CANT_CREATE_GEOMETRY_OBJECT
INSERT INTO t3 VALUES
(1,
(SELECT target FROM t2 ORDER BY id LIMIT 1),
(SELECT source FROM t2 ORDER BY id LIMIT 1)),
(2,
(SELECT source FROM t2 ORDER BY id LIMIT 1),
(SELECT source FROM t2 ORDER BY id LIMIT 1));
SELECT * FROM v3;
TRUNCATE TABLE t3;

SET sql_mode=STRICT_ALL_TABLES;
--error ER_TRUNCATED_WRONG_VALUE, ER_TRUNCATED_WRONG_VALUE_FOR_FIELD, WARN_DATA_TRUNCATED, ER_CANT_CREATE_GEOMETRY_OBJECT
INSERT INTO t3 VALUES
(1,
(SELECT target FROM t2 ORDER BY id LIMIT 1),
(SELECT source FROM t2 ORDER BY id LIMIT 1)),
(2,
(SELECT source FROM t2 ORDER BY id LIMIT 1),
(SELECT source FROM t2 ORDER BY id LIMIT 1));
SELECT * FROM v3;
TRUNCATE TABLE t3;
SET sql_mode=DEFAULT;
DROP TABLE t3;
DROP VIEW v3;

#
# INSERT .. SELECT
#

CREATE TABLE t3 LIKE t2;
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
INSERT INTO t3 SELECT id,source,source FROM t2;

--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
INSERT INTO t3 (id,target,source) SELECT id,source,source FROM t2;

#
# INSERT .. VALUES .. ON DUPLICATE KEY UPDATE target=source
#

--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
INSERT INTO t3 VALUES (1,DEFAULT,DEFAULT) ON DUPLICATE KEY UPDATE target=source;

--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
INSERT INTO t3 (id,target,source) VALUES (1,DEFAULT,DEFAULT) ON DUPLICATE KEY UPDATE target=source;

#
# INSERT .. SELECT .. ON DUPLICATE KEY UPDATE target=source
#

--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
INSERT INTO t3 SELECT 1,DEFAULT(t2.target),DEFAULT(t2.source) FROM t2 ON DUPLICATE KEY UPDATE t3.target=t2.source;

--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
INSERT INTO t3 (id,target,source) SELECT 1,DEFAULT(t2.target),DEFAULT(t2.source) FROM t2 ON DUPLICATE KEY UPDATE t3.target=t2.source;


#
# UPDATE
#
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
UPDATE t3 SET target=source;


#
# UPDATE, multi-table
#

--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
UPDATE t2, t3 SET t3.target=t2.source WHERE t2.id=t3.id;


#
# ALTER
#

SET @alter=CONCAT('ALTER TABLE t3 MODIFY target ', @source_type);
SELECT @alter;
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
EXECUTE IMMEDIATE @alter;


DROP TABLE t3;
DROP TABLE t2;
--echo # End of type_store_assignment_incompatible.inc
@@ -1152,11 +1152,11 @@ SELECT @var62, @var63;
@var62 @var63
1 NULL
INSERT INTO t1 SELECT id2, val2, p2 from t2;
ERROR 22007: Incorrect double value: '\x00\x00\x00\x00\x01\x01\x00\x00\x00\x00\x00\x00\x00\x00\x004@\x00\x00\x00\x00\x00\x00$@' for column `test`.`t1`.`d1` at row 1
ERROR HY000: Illegal parameter data types double and point for operation 'SET'
GET DIAGNOSTICS CONDITION 1 @var64= ROW_NUMBER;
GET DIAGNOSTICS CONDITION 2 @var65= ROW_NUMBER;
Warnings:
Error 1366 Incorrect double value: '\x00\x00\x00\x00\x01\x01\x00\x00\x00\x00\x00\x00\x00\x00\x004@\x00\x00\x00\x00\x00\x00$@' for column `test`.`t1`.`d1` at row 1
Error 4078 Illegal parameter data types double and point for operation 'SET'
Error 1758 Invalid condition number
SELECT @var64, @var65;
@var64 @var65
@@ -1396,11 +1396,11 @@ SELECT @var103, @var104;
@var103 @var104
1 NULL
INSERT INTO t1 SELECT id2, val2, p2 from t2;
ERROR 22007: Incorrect double value: '\x00\x00\x00\x00\x01\x01\x00\x00\x00\x00\x00\x00\x00\x00\x004@\x00\x00\x00\x00\x00\x00$@' for column `test`.`t1`.`d1` at row 1
ERROR HY000: Illegal parameter data types double and point for operation 'SET'
GET DIAGNOSTICS CONDITION 1 @var105= ROW_NUMBER;
GET DIAGNOSTICS CONDITION 2 @var106= ROW_NUMBER;
Warnings:
Error 1366 Incorrect double value: '\x00\x00\x00\x00\x01\x01\x00\x00\x00\x00\x00\x00\x00\x00\x004@\x00\x00\x00\x00\x00\x00$@' for column `test`.`t1`.`d1` at row 1
Error 4078 Illegal parameter data types double and point for operation 'SET'
Error 1758 Invalid condition number
SELECT @var105, @var106;
@var105 @var106
@@ -1091,7 +1091,7 @@ GET DIAGNOSTICS CONDITION 1 @var62= ROW_NUMBER;
GET DIAGNOSTICS CONDITION 2 @var63= ROW_NUMBER;
SELECT @var62, @var63;

--error ER_TRUNCATED_WRONG_VALUE_FOR_FIELD
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
INSERT INTO t1 SELECT id2, val2, p2 from t2;
GET DIAGNOSTICS CONDITION 1 @var64= ROW_NUMBER;
GET DIAGNOSTICS CONDITION 2 @var65= ROW_NUMBER;
@@ -1277,7 +1277,7 @@ GET DIAGNOSTICS CONDITION 1 @var103= ROW_NUMBER;
GET DIAGNOSTICS CONDITION 2 @var104= ROW_NUMBER;
SELECT @var103, @var104;

--error ER_TRUNCATED_WRONG_VALUE_FOR_FIELD
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
INSERT INTO t1 SELECT id2, val2, p2 from t2;
GET DIAGNOSTICS CONDITION 1 @var105= ROW_NUMBER;
GET DIAGNOSTICS CONDITION 2 @var106= ROW_NUMBER;
@@ -688,9 +688,9 @@ object_id geometrytype(geo) ISSIMPLE(GEO) ASTEXT(centroid(geo))
drop table t1;
create table t1 (fl geometry not null);
insert into t1 values (1);
ERROR 22003: Cannot get geometry object from data you send to the GEOMETRY field
ERROR HY000: Illegal parameter data types geometry and int for operation 'SET'
insert into t1 values (1.11);
ERROR 22003: Cannot get geometry object from data you send to the GEOMETRY field
ERROR HY000: Illegal parameter data types geometry and decimal for operation 'SET'
insert into t1 values ("qwerty");
ERROR 22003: Cannot get geometry object from data you send to the GEOMETRY field
insert into t1 values (pointfromtext('point(1,1)'));
@@ -366,9 +366,9 @@ t1 where object_id=85984;
drop table t1;

create table t1 (fl geometry not null);
--error 1416
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
insert into t1 values (1);
--error 1416
--error ER_ILLEGAL_PARAMETER_DATA_TYPES2_FOR_OPERATION
insert into t1 values (1.11);
--error 1416
insert into t1 values ("qwerty");

0 comments on commit 0bed4d7

Please sign in to comment.