Commit 79e1c0fd authored by unknown's avatar unknown

New way to fix BUG#19243 "wrong LAST_INSERT_ID() after ON DUPLICATE KEY UPDATE".

This bug report was two problems:
1) LAST_INSERT_ID() returns a value which does not exist in the table
2) the reporter would want it to return the autoinc id of the updated
row.
1) is a real bug, 2) is a feature request.
In July I implemented 2) in 5.1 (which automatically fixes 1).
This has not yet been documented or released, so is changeable.
Precisely, recently Paul and a user found an easy workaround to give
2), which works in 4.1-5.0-5.1. So I can revert my code for 2),
because it's not needed, that's what I do here;
we forget about 2) (we will document the workaround).
But when I revert my code for 2), 1) comes back. We solve 1) by saying
that if INSERT ON DUPLICATE KEY UPDATE updates a row, it's like a
regular UPDATE: LAST_INSERT_ID() should not be affected (instead of
returning a non-existent value).
So note: no behaviour change compared to the last released 5.1; just
a bugfix for 1).


mysql-test/r/innodb_mysql.result:
  result update
mysql-test/t/innodb_mysql.test:
      test for the new way to fix BUG#19243: that if INSERT ON DUPLICATE
      KEY UPDATE updates a row, SELECT LAST_INSERT_ID() is not affected.
      Test of the workaround for people who want SELECT LAST_INSERT_ID()
      to return the autoinc id of the updated row.
sql/sql_insert.cc:
  No need to change LAST_INSERT_ID() if INSERT ON DUPLICATE KEY UPDATE
  updates a row, there is a workaround to achieve this without changing
  code: just add "autoinc_col=LAST_INSERT_ID(autoinc_col)" to your
  ON DUPLICATE KEY UPDATE clause.
  Prevent LAST_INSERT_ID() to contain an inexistent value in this case:
  if the row is updated it should be like a regular UPDATE: don't
  affect LAST_INSERT_ID() (achieved by marking that we didn't generate
  an id for this row: insert_id_for_cur_row=0).
parent 1ecb3e11
...@@ -432,22 +432,44 @@ ifnull( c, ...@@ -432,22 +432,44 @@ ifnull( c,
0 ) + 1; 0 ) + 1;
select last_insert_id(); select last_insert_id();
last_insert_id() last_insert_id()
1 2
select last_insert_id(0);
last_insert_id(0)
0
insert into t2 ( a ) values ( 6 ) on duplicate key update c =
ifnull( c,
0 ) + 1;
select last_insert_id();
last_insert_id()
0
select * from t2; select * from t2;
k a c k a c
1 6 1 1 6 2
2 7 NULL 2 7 NULL
insert ignore into t2 values (null,6,1),(10,8,1); insert ignore into t2 values (null,6,1),(10,8,1);
select last_insert_id(); select last_insert_id();
last_insert_id() last_insert_id()
1 0
insert ignore into t2 values (null,6,1),(null,8,1),(null,15,1),(null,20,1); insert ignore into t2 values (null,6,1),(null,8,1),(null,15,1),(null,20,1);
select last_insert_id(); select last_insert_id();
last_insert_id() last_insert_id()
11 11
select * from t2; select * from t2;
k a c k a c
1 6 1 1 6 2
2 7 NULL
10 8 1
11 15 1
12 20 1
insert into t2 ( a ) values ( 6 ) on duplicate key update c =
ifnull( c,
0 ) + 1, k=last_insert_id(k);
select last_insert_id();
last_insert_id()
1
select * from t2;
k a c
1 6 3
2 7 NULL 2 7 NULL
10 8 1 10 8 1
11 15 1 11 15 1
......
...@@ -369,8 +369,8 @@ insert into t1 values('aaa'); ...@@ -369,8 +369,8 @@ insert into t1 values('aaa');
drop table t1; drop table t1;
# Fix for BUG#19243 "wrong LAST_INSERT_ID() after ON DUPLICATE KEY # Fix for BUG#19243 "wrong LAST_INSERT_ID() after ON DUPLICATE KEY
# UPDATE": now LAST_INSERT_ID() will return the id of the updated # UPDATE": if the row is updated, it's like a regular UPDATE:
# row. # LAST_INSERT_ID() is not affected.
CREATE TABLE `t2` ( CREATE TABLE `t2` (
`k` int(11) NOT NULL auto_increment, `k` int(11) NOT NULL auto_increment,
`a` int(11) default NULL, `a` int(11) default NULL,
...@@ -390,6 +390,12 @@ insert into t2 ( a ) values ( 6 ) on duplicate key update c = ...@@ -390,6 +390,12 @@ insert into t2 ( a ) values ( 6 ) on duplicate key update c =
ifnull( c, ifnull( c,
0 ) + 1; 0 ) + 1;
select last_insert_id(); select last_insert_id();
# test again when last_insert_id() is 0 initially
select last_insert_id(0);
insert into t2 ( a ) values ( 6 ) on duplicate key update c =
ifnull( c,
0 ) + 1;
select last_insert_id();
select * from t2; select * from t2;
# Test of LAST_INSERT_ID() when autogenerated will fail: # Test of LAST_INSERT_ID() when autogenerated will fail:
...@@ -402,5 +408,14 @@ insert ignore into t2 values (null,6,1),(null,8,1),(null,15,1),(null,20,1); ...@@ -402,5 +408,14 @@ insert ignore into t2 values (null,6,1),(null,8,1),(null,15,1),(null,20,1);
select last_insert_id(); select last_insert_id();
select * from t2; select * from t2;
drop table t2; # Test of the workaround which enables people to know the id of the
# updated row in INSERT ON DUPLICATE KEY UPDATE, by using
# LAST_INSERT_ID(autoinc_col) in the UPDATE clause.
insert into t2 ( a ) values ( 6 ) on duplicate key update c =
ifnull( c,
0 ) + 1, k=last_insert_id(k);
select last_insert_id();
select * from t2;
drop table t2;
...@@ -1145,16 +1145,15 @@ int write_record(THD *thd, TABLE *table,COPY_INFO *info) ...@@ -1145,16 +1145,15 @@ int write_record(THD *thd, TABLE *table,COPY_INFO *info)
} }
info->updated++; info->updated++;
/* /*
If ON DUP KEY UPDATE updates a row instead of inserting one, and If ON DUP KEY UPDATE updates a row instead of inserting one, it's
there is an auto_increment column, then SELECT LAST_INSERT_ID() like a regular UPDATE statement: it should not affect the value of a
returns the id of the updated row: next SELECT LAST_INSERT_ID() or mysql_insert_id().
Except if LAST_INSERT_ID(#) was in the INSERT query, which is
handled separately by THD::arg_of_last_insert_id_function.
*/ */
insert_id_for_cur_row= table->file->insert_id_for_cur_row= 0;
if (table->next_number_field) if (table->next_number_field)
{ table->file->adjust_next_insert_id_after_explicit_value(table->next_number_field->val_int());
longlong field_val= table->next_number_field->val_int();
thd->record_first_successful_insert_id_in_cur_stmt(field_val);
table->file->adjust_next_insert_id_after_explicit_value(field_val);
}
trg_error= (table->triggers && trg_error= (table->triggers &&
table->triggers->process_triggers(thd, TRG_EVENT_UPDATE, table->triggers->process_triggers(thd, TRG_EVENT_UPDATE,
TRG_ACTION_AFTER, TRUE)); TRG_ACTION_AFTER, TRUE));
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment