Uploaded image for project: 'MariaDB Server'
  1. MariaDB Server
  2. MDEV-4826

UPDATE in Stored Function is not rolled back

    Details

    • Type: Bug
    • Status: Open
    • Priority: Minor
    • Resolution: Unresolved
    • Affects Version/s: 10.0.3, 5.5.32, 5.1.67, 5.2.14, 5.3.12, 10.0.10
    • Fix Version/s: 5.5
    • Component/s: None
    • Labels:

      Description

      This happened to me in 10.0 on WinXP; don't know about other platforms/versions.

      First, I create a 2-rows table with a primary key. Then I start a transaction and invoke a function which tries to set both values to 10. The first value is updated, the second value fails (duplicate value), but the first operation is not rollback, so I get a row with id=10.

      Here's the code:

      DELIMITER ||
      USE test;
      DROP TABLE IF EXISTS t1, t2;
      DROP FUNCTION IF EXISTS f1;
      CREATE TABLE t1 (
      	id TINYINT UNSIGNED PRIMARY KEY
      ) ENGINE=InnoDB;
      INSERT INTO t1
      	VALUES
      		(1),
      		(2);
      CREATE FUNCTION f1() RETURNS TEXT
      BEGIN
      	DECLARE CONTINUE HANDLER
      		FOR 1062
      		DO NULL;
      	UPDATE t1 SET id = 10 ORDER BY id ASC;
      	RETURN TRUE;
      END;
      ||
      DELIMITER ;
      SET autocommit = 0;
      START TRANSACTION;
      SELECT f1();
      COMMIT;
      SHOW WARNINGS;
      SELECT * FROM t1;
      

      As far as I understand from this page, this is a bug:
      http://dev.mysql.com/doc/refman/5.6/en/innodb-error-handling.html
      "A duplicate-key error rolls back the SQL statement, if you have not specified the IGNORE option in your statement."

      In my test a DECLARE CONTINUE HANDLER is used, but I couldn't find transaction information in the DECLARE HANDLER page or similar pages.

        Gliffy Diagrams

          Attachments

            Issue Links

              Activity

              Hide
              elenst Elena Stepanova added a comment -

              Hi Federico,

              It seems to be a tricky issue.
              On one hand, the current behavior looks logical me. You specifically instruct your function to ignore the duplicate key condition by adding an empty continue handler:
              DECLARE CONTINUE HANDLER
              FOR 1062
              DO NULL;

              If you hadn't done that, the result would have been as you expected.

              On the other hand, it's not as obvious as a case with two subsequent updates would have been:
              DECLARE CONTINUE HANDLER
              FOR 1062
              DO NULL;
              UPDATE t1 SET id = 10 WHERE id = 1;
              UPDATE t1 SET id = 10 WHERE id = 2;

              Here one could totally expect the result of the first statement to be preserved; but should it be so inside a single statement? I can't say for certain one way or another. My bet is on "it's by design (of error handlers in stored procedures)", but if you have doubts, I can get a second opinion. Alternatively, you can try to file a bug at MySQL and see what they think about it (it works the same way in MySQL).

              One thing is obvious though, the behavior of InnoDB error handling together with stored procedures error handling should be documented somewhere; maybe it is, but I couldn't find it. So, at least the doc request is due.

              Show
              elenst Elena Stepanova added a comment - Hi Federico, It seems to be a tricky issue. On one hand, the current behavior looks logical me. You specifically instruct your function to ignore the duplicate key condition by adding an empty continue handler: DECLARE CONTINUE HANDLER FOR 1062 DO NULL; If you hadn't done that, the result would have been as you expected. On the other hand, it's not as obvious as a case with two subsequent updates would have been: DECLARE CONTINUE HANDLER FOR 1062 DO NULL; UPDATE t1 SET id = 10 WHERE id = 1; UPDATE t1 SET id = 10 WHERE id = 2; Here one could totally expect the result of the first statement to be preserved; but should it be so inside a single statement? I can't say for certain one way or another. My bet is on "it's by design (of error handlers in stored procedures)", but if you have doubts, I can get a second opinion. Alternatively, you can try to file a bug at MySQL and see what they think about it (it works the same way in MySQL). One thing is obvious though, the behavior of InnoDB error handling together with stored procedures error handling should be documented somewhere; maybe it is, but I couldn't find it. So, at least the doc request is due.
              Hide
              f_razzoli Federico Razzoli added a comment -

              Hi Elena,
              Thanks for your answer.
              I don't have an opinion about what behavior is correct. What really confuses me is that I can't find this information in the docs. So I am not sure if this behaviour is intended and, most importantly for me, if I can expect it to remain the same in future versions.

              Show
              f_razzoli Federico Razzoli added a comment - Hi Elena, Thanks for your answer. I don't have an opinion about what behavior is correct. What really confuses me is that I can't find this information in the docs. So I am not sure if this behaviour is intended and, most importantly for me, if I can expect it to remain the same in future versions.
              Hide
              f_razzoli Federico Razzoli added a comment -

              Hi again,
              I tried to repeat a very similar test, but using a Stoed Procedure instead of a Function. In this case, the transaction IS rolled back. There may be some reason I don't understand... but still, I wasn't able to find any information in the docs which warns users about this difference:

              MariaDB [test]> DELIMITER ||
              MariaDB [test]> DROP TABLE IF EXISTS t1;
                  -> DROP PROCEDURE IF EXISTS sp1;
                  -> CREATE TABLE t1 (
                  ->  id TINYINT UNSIGNED PRIMARY KEY
                  -> ) ENGINE=InnoDB;
                  -> INSERT INTO t1
                  ->  VALUES
                  ->          (1),
                  ->          (2);
                  -> CREATE PROCEDURE sp1()
                  -> BEGIN
                  ->  DECLARE CONTINUE HANDLER
                  ->          FOR 1062
                  ->          DO NULL;
                  ->  UPDATE t1 SET id = 10 ORDER BY id ASC;
                  -> END;
                  -> ||
              Query OK, 0 rows affected (0.11 sec)
              
              Query OK, 0 rows affected (0.35 sec)
              
              Query OK, 0 rows affected (0.70 sec)
              
              Query OK, 2 rows affected (0.94 sec)
              Records: 2  Duplicates: 0  Warnings: 0
              
              Query OK, 0 rows affected (1.33 sec)
              
              MariaDB [test]> DELIMITER ;
              MariaDB [test]> SET autocommit = 0;
              Query OK, 0 rows affected (0.00 sec)
              
              MariaDB [test]> START TRANSACTION;
              Query OK, 0 rows affected (0.00 sec)
              
              MariaDB [test]> CALL sp1();
              Query OK, 0 rows affected, 1 warning (0.00 sec)
              
              MariaDB [test]> COMMIT;
              Query OK, 0 rows affected (0.08 sec)
              
              MariaDB [test]> SHOW WARNINGS;
              +-------+------+----------------------------------------+
              | Level | Code | Message                                |
              +-------+------+----------------------------------------+
              | Error | 1062 | Duplicate entry '10' for key 'PRIMARY' |
              +-------+------+----------------------------------------+
              1 row in set (0.01 sec)
              
              MariaDB [test]> SELECT * FROM t1;
              +----+
              | id |
              +----+
              |  1 |
              |  2 |
              +----+
              2 rows in set (0.00 sec)
              
              Show
              f_razzoli Federico Razzoli added a comment - Hi again, I tried to repeat a very similar test, but using a Stoed Procedure instead of a Function. In this case, the transaction IS rolled back. There may be some reason I don't understand... but still, I wasn't able to find any information in the docs which warns users about this difference: MariaDB [test]> DELIMITER || MariaDB [test]> DROP TABLE IF EXISTS t1; -> DROP PROCEDURE IF EXISTS sp1; -> CREATE TABLE t1 ( -> id TINYINT UNSIGNED PRIMARY KEY -> ) ENGINE=InnoDB; -> INSERT INTO t1 -> VALUES -> (1), -> (2); -> CREATE PROCEDURE sp1() -> BEGIN -> DECLARE CONTINUE HANDLER -> FOR 1062 -> DO NULL; -> UPDATE t1 SET id = 10 ORDER BY id ASC; -> END; -> || Query OK, 0 rows affected (0.11 sec) Query OK, 0 rows affected (0.35 sec) Query OK, 0 rows affected (0.70 sec) Query OK, 2 rows affected (0.94 sec) Records: 2 Duplicates: 0 Warnings: 0 Query OK, 0 rows affected (1.33 sec) MariaDB [test]> DELIMITER ; MariaDB [test]> SET autocommit = 0; Query OK, 0 rows affected (0.00 sec) MariaDB [test]> START TRANSACTION; Query OK, 0 rows affected (0.00 sec) MariaDB [test]> CALL sp1(); Query OK, 0 rows affected, 1 warning (0.00 sec) MariaDB [test]> COMMIT; Query OK, 0 rows affected (0.08 sec) MariaDB [test]> SHOW WARNINGS; +-------+------+----------------------------------------+ | Level | Code | Message | +-------+------+----------------------------------------+ | Error | 1062 | Duplicate entry '10' for key 'PRIMARY' | +-------+------+----------------------------------------+ 1 row in set (0.01 sec) MariaDB [test]> SELECT * FROM t1; +----+ | id | +----+ | 1 | | 2 | +----+ 2 rows in set (0.00 sec)
              Hide
              elenst Elena Stepanova added a comment -

              Yes, I agree, that's weird. I think it's worth filing for upstream and seeing what they say – if nothing else, this way we'll get it documented.
              Are you willing to file a bug at bugs.mysql.com, or should I do it on your behalf?

              Show
              elenst Elena Stepanova added a comment - Yes, I agree, that's weird. I think it's worth filing for upstream and seeing what they say – if nothing else, this way we'll get it documented. Are you willing to file a bug at bugs.mysql.com, or should I do it on your behalf?
              Hide
              f_razzoli Federico Razzoli added a comment -

              I'm sorry, I dont want to register on Oracle site because they ask too many personal information.

              Show
              f_razzoli Federico Razzoli added a comment - I'm sorry, I dont want to register on Oracle site because they ask too many personal information.
              Hide
              elenst Elena Stepanova added a comment -

              No problem, I understand your point. Filed as http://bugs.mysql.com/bug.php?id=69872

              Show
              elenst Elena Stepanova added a comment - No problem, I understand your point. Filed as http://bugs.mysql.com/bug.php?id=69872
              Hide
              elenst Elena Stepanova added a comment -

              It turned out to be a duplicate of http://bugs.mysql.com/bug.php?id=51006. I pressed the "Affect me" button on your behalf

              Show
              elenst Elena Stepanova added a comment - It turned out to be a duplicate of http://bugs.mysql.com/bug.php?id=51006 . I pressed the "Affect me" button on your behalf

                People

                • Assignee:
                  Unassigned
                  Reporter:
                  f_razzoli Federico Razzoli
                • Votes:
                  0 Vote for this issue
                  Watchers:
                  3 Start watching this issue

                  Dates

                  • Created:
                    Updated: