Bug #59715 UPDATE IGNORE, 1 row affected
Submitted: 25 Jan 2011 14:15 Modified: 20 Dec 2011 4:41
Reporter: ttt ttt Email Updates:
Status: Closed Impact on me:
None 
Category:MySQL Server: Errors Severity:S3 (Non-critical)
Version:5.1.54 OS:Any
Assigned to: CPU Architecture:Any

[25 Jan 2011 14:15] ttt ttt
Description:
CREATE TABLE `test_update` ( `test` int(11) NOT NULL default '5', `id` int(11) NOT NULL auto_increment, PRIMARY KEY  (`id`)) ENGINE=MyISAM

INSERT INTO `test_update` (`id`) VALUES ('1'), ('2');

How to repeat:
mysql> SELECT * FROM `test_update` WHERE 1;
+------+----+
| test | id |
+------+----+
|    5 |  1 |
|    5 |  2 |
+------+----+
2 rows in set (0.00 sec)

UPDATE  IGNORE `test_update`, (SELECT 4 as `test`,2 as `id`, 1 as `new_id`) as `tbl1` SET `test_update`.`test`=`tbl1`.`test`, `test_update`.`id`=`tbl1`.`new_id` WHERE `test_update`.`id`=`tbl1`.`id`

Query OK, 1 row affected (0.00 sec)
Rows matched: 1  Changed: 1  Warnings: 0

mysql>  SELECT * FROM `test_update` WHERE 1;
+------+----+
| test | id |
+------+----+
|    5 |  1 |
|    5 |  2 |
+------+----+
2 rows in set (0.00 sec)

Suggested fix:
count -- after found duplicate key
[25 Jan 2011 15:20] Valeriy Kravchuk
Verified with 5.1.54:

C:\Program Files\MySQL\MySQL Server 5.1\bin>mysql -uroot -proot -P3310 test
Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 19
Server version: 5.1.54-community MySQL Community Server (GPL)

Copyright (c) 2000, 2010, Oracle and/or its affiliates. All rights reserved.
This software comes with ABSOLUTELY NO WARRANTY. This is free software,
and you are welcome to modify and redistribute it under the GPL v2 license

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql> CREATE TABLE `test_update` ( `test` int(11) NOT NULL default '5', `id` in
t(11) NOT NULL
    -> auto_increment, PRIMARY KEY  (`id`)) ENGINE=MyISAM
    -> ;
Query OK, 0 rows affected (0.06 sec)

mysql> INSERT INTO `test_update` (`id`) VALUES ('1'), ('2');
Query OK, 2 rows affected (0.01 sec)
Records: 2  Duplicates: 0  Warnings: 0

mysql>  SELECT * FROM `test_update`;
+------+----+
| test | id |
+------+----+
|    5 |  1 |
|    5 |  2 |
+------+----+
2 rows in set (0.00 sec)

mysql> UPDATE  IGNORE `test_update`, (SELECT 4 as `test`,2 as `id`, 1 as `new_id
`) as `tbl1` SET
    -> `test_update`.`test`=`tbl1`.`test`, `test_update`.`id`=`tbl1`.`new_id` WH
ERE
    -> `test_update`.`id`=`tbl1`.`id`
    ->
    -> ;
Query OK, 1 row affected (0.03 sec)
Rows matched: 1  Changed: 1  Warnings: 0

mysql>  SELECT * FROM `test_update`;
+------+----+
| test | id |
+------+----+
|    5 |  1 |
|    5 |  2 |
+------+----+
2 rows in set (0.00 sec)

Our manual, http://dev.mysql.com/doc/refman/5.1/en/update.html, clearly says:

"UPDATE returns the number of rows that were actually changed."

No rows were actually changed in the case above. Compare to the following (same update but with explicit constants, not multiple-table update):

mysql> UPDATE  IGNORE `test_update` SET id = 1 where id = 2;
Query OK, 0 rows affected (0.03 sec)
Rows matched: 1  Changed: 0  Warnings: 0
[20 Dec 2011 4:41] Paul DuBois
Noted in 5.6.5 changelog.

UPDATE IGNORE returned an incorrect count for number of rows updated
when there were duplicate-key conflicts in a multiple-table update.