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

Wrong insert with ordering due to join or subquery

    Details

    • Type: Bug
    • Status: Closed
    • Priority: Major
    • Resolution: Not a Bug
    • Affects Version/s: None
    • Fix Version/s: None
    • Component/s: None
    • Labels:
    • Environment:
      Debian squeeze (x64)

      Description

      I need to insert data from a SELECT query with an ORDER BY and a SQL variable (like @a). The final query look like this :

      SET @var=0;
      INSERT INTO rank (position,petId,userId) SELECT (@var:=@var+1), id, userId FROM pet ORDER BY p.experience DESC ON DUPLICATE KEY UPDATE oldPosition=position, position=VALUES(position);
      

      Result look like :

      position petId userId
      1 15 6
      2 24 12
      3 7 4
      ...

      It work but when I want to add a JOIN in this query, the ordering does not work (use natural ordering) :

      SET @var=0;
      INSERT INTO rank (position,petId,userId) SELECT (@var:=@var+1), p.id, p.userId, FROM pet AS p JOIN user AS u ON p.userId = u.id AND u.lastConnection >= ADDDATE(NOW(), INTERVAL -1 MONTH) ORDER BY p.experience DESC ON DUPLICATE KEY UPDATE oldPosition=position, position=VALUES(position);
      
      position petId userId
      1 1 1
      2 2 1
      3 3 2
      ...

      I already test it with an INNER JOIN or a subquery but it return the same result.
      Note : This request (with JOIN) work fine on MYSQL.
      Note2 : We use MariaDB 5.5.32 (I don't find this version on your "Affects [...]" list).
      Note3 : We are using InnoDB engine.

        Gliffy Diagrams

          Attachments

            Issue Links

              Activity

              Hide
              elenst Elena Stepanova added a comment -

              Hi,

              When you are saying that it works fine on MySQL, which version do you have in mind? From all I see the last version that was this lucky is 5.0, is it really what you are using?

              I'm getting the "misordered" result on all of MySQL 5.1-5.7 as well as MariaDB 5.1-10.0:

              create table rank (position INT, petId INT, userId INT, oldPosition INT, PRIMARY KEY (userId, petId)) engine=MyISAM;
              create table pet (experience INT, id INT, userId INT, PRIMARY KEY(id)) engine=MyISAM;
              create table user (id INT, lastConnection DATETIME, PRIMARY KEY(id)) engine=MyISAM;
              INSERT INTO pet VALUES (10, 15, 1), (2, 20, 1), (12, 7, 2);
              INSERT INTO user VALUES (1, NOW()), (2, NOW());
              SET @var=0;
              INSERT INTO rank (position,petId,userId) SELECT (@var:=@var+1), id, userId FROM pet ORDER BY experience DESC ON DUPLICATE KEY UPDATE oldPosition=position, position=VALUES(position);
              select * from rank order by position;
              position petId userId oldPosition
              1 7 2 NULL
              2 15 1 NULL
              3 20 1 NULL
              truncate rank;
              SET @var=0;
              INSERT INTO rank (position,petId,userId) SELECT (@var:=@var+1), p.id, p.userId FROM pet AS p JOIN user AS u ON p.userId = u.id AND u.lastConnection >= ADDDATE(NOW(), INTERVAL -1 MONTH) ORDER BY p.experience DESC ON DUPLICATE KEY UPDATE oldPosition=position, position=VALUES(position);
              select * from rank order by position;
              position petId userId oldPosition
              1 15 1 NULL
              2 20 1 NULL
              3 7 2 NULL
              select @@version;
              @@version
              5.7.2-m12-debug-log

              MySQL thinks it's not a bug, here is the example:
              http://bugs.mysql.com/bug.php?id=47517

              However, I haven't found anything in documentation that says so, thus I'll go for the expert opinion. Assigning to Sanja for this purpose.

              Show
              elenst Elena Stepanova added a comment - Hi, When you are saying that it works fine on MySQL, which version do you have in mind? From all I see the last version that was this lucky is 5.0, is it really what you are using? I'm getting the "misordered" result on all of MySQL 5.1-5.7 as well as MariaDB 5.1-10.0: create table rank (position INT, petId INT, userId INT, oldPosition INT, PRIMARY KEY (userId, petId)) engine=MyISAM; create table pet (experience INT, id INT, userId INT, PRIMARY KEY(id)) engine=MyISAM; create table user (id INT, lastConnection DATETIME, PRIMARY KEY(id)) engine=MyISAM; INSERT INTO pet VALUES (10, 15, 1), (2, 20, 1), (12, 7, 2); INSERT INTO user VALUES (1, NOW()), (2, NOW()); SET @var=0; INSERT INTO rank (position,petId,userId) SELECT (@var:=@var+1), id, userId FROM pet ORDER BY experience DESC ON DUPLICATE KEY UPDATE oldPosition=position, position=VALUES(position); select * from rank order by position; position petId userId oldPosition 1 7 2 NULL 2 15 1 NULL 3 20 1 NULL truncate rank; SET @var=0; INSERT INTO rank (position,petId,userId) SELECT (@var:=@var+1), p.id, p.userId FROM pet AS p JOIN user AS u ON p.userId = u.id AND u.lastConnection >= ADDDATE(NOW(), INTERVAL -1 MONTH) ORDER BY p.experience DESC ON DUPLICATE KEY UPDATE oldPosition=position, position=VALUES(position); select * from rank order by position; position petId userId oldPosition 1 15 1 NULL 2 20 1 NULL 3 7 2 NULL select @@version; @@version 5.7.2-m12-debug-log MySQL thinks it's not a bug, here is the example: http://bugs.mysql.com/bug.php?id=47517 However, I haven't found anything in documentation that says so, thus I'll go for the expert opinion. Assigning to Sanja for this purpose.
              Hide
              LauBee Pelvillain Laurent added a comment -

              Hello Elena,

              We are using Mysql 5.1.61-0+squeeze1. The main difference with your test is that we are not using MyISAM but InnoDB engine.
              I have processed the same test on the twice engine and it works only on InnoDB with Mysql 5.1.61.
              Sorry, I forgot to point out the engine used.

              Show
              LauBee Pelvillain Laurent added a comment - Hello Elena, We are using Mysql 5.1.61-0+squeeze1. The main difference with your test is that we are not using MyISAM but InnoDB engine. I have processed the same test on the twice engine and it works only on InnoDB with Mysql 5.1.61. Sorry, I forgot to point out the engine used.
              Hide
              sanja Oleksandr Byelkin added a comment -

              SELECT list (and so variables) calculated on unsorted data, and then ORDER BY applied to the result.

              So if above query was working somewhere then it is just good luck, result of it very depends on execution plan, used storage engine and for some engines even in which order the tables was filled.

              You should use some other (more reliable) mechanistam to get what you want, the first what came to my mind is intermidiate (temporary?) table with autoincrement. Maybe there is some other solution also...

              Show
              sanja Oleksandr Byelkin added a comment - SELECT list (and so variables) calculated on unsorted data, and then ORDER BY applied to the result. So if above query was working somewhere then it is just good luck, result of it very depends on execution plan, used storage engine and for some engines even in which order the tables was filled. You should use some other (more reliable) mechanistam to get what you want, the first what came to my mind is intermidiate (temporary?) table with autoincrement. Maybe there is some other solution also...

                People

                • Assignee:
                  sanja Oleksandr Byelkin
                  Reporter:
                  LauBee Pelvillain Laurent
                • Votes:
                  0 Vote for this issue
                  Watchers:
                  4 Start watching this issue

                  Dates

                  • Due:
                    Created:
                    Updated:
                    Resolved: