Details

    • Bug
    • Status: Closed (View Workflow)
    • Major
    • Resolution: Fixed
    • 10.2.2
    • 10.2.6
    • Optimizer - CTE
    • Linux Mint 18 64-bit

    Description

      Joe Celko's "Classroom scheduling problem" has a classic CTE solution that works unproblematically eg in SQL Server 2014 and PostgreSQL 9.6, but fails in MariaDB 10.2.2. An explanation of the query problem and its CTE solution is here.

      DROP TABLE IF EXISTS Rooms, Classes; 
      CREATE TABLE Rooms( 
        room_nbr CHAR(2) NOT NULL PRIMARY KEY, room_size INTEGER NOT NULL 
      ) ; 
      CREATE TABLE Classes( 
        class_nbr CHAR(2) NOT NULL PRIMARY KEY, class_size INTEGER NOT NULL 
      ) ; 
      INSERT INTO Classes   
      VALUES ('c1', 80),('c2', 70),('c3', 65),('c4', 55),('c5', 50),('c6', 40); 
      INSERT INTO Rooms  
      VALUES ('r1', 70),('r2', 40),('r3', 50),('r4', 85),('r5', 30),('r6', 65),('r7', 55); 
       
      WITH  
        Matches AS ( 
          SELECT  
            class_nbr, class_size, room_nbr, room_size,  
            CASE WHEN class_size = room_size THEN 1 ELSE 0 END AS exact_match 
          FROM Classes 
          JOIN Rooms ON class_size <= room_size 
        ), 
        Preferences AS ( 
          SELECT 
            class_nbr, class_size,  
            ROW_NUMBER() OVER ( 
              PARTITION BY class_nbr ORDER BY exact_match, room_size, room_nbr 
            ) AS class_room_pref,
            room_nbr, room_size,  
            ROW_NUMBER() OVER ( 
              PARTITION BY room_nbr ORDER BY exact_match, class_size DESC, class_nbr 
            ) AS room_class_pref
          FROM Matches m 
          WHERE NOT EXISTS (  
            SELECT 1 FROM Matches WHERE room_nbr = m.room_nbr AND class_size > m.class_size 
          ) 
        ), 
        Final AS ( 
          SELECT 
            class_nbr, class_size, room_nbr, room_size, 
            ROW_NUMBER() OVER (
              PARTITION BY class_nbr ORDER BY class_room_pref
            ) AS final_pref
          FROM Preferences p 
          WHERE NOT EXISTS ( 
            SELECT 1 FROM Preferences 
            WHERE room_nbr = p.room_nbr  
              AND class_room_pref = room_class_pref  
              AND  room_class_pref < p.room_class_pref 
          ) 
        ) 
      SELECT c.class_nbr, c.class_size, f.room_nbr, f.room_size 
      FROM Classes c 
      LEFT JOIN Final f ON c.class_nbr = f.class_nbr AND f.final_pref = 1 
      ORDER BY 1; 
      

      MariaDB 10.2.2 responds with: "Table 'test.Matches' doesn't exist."

      Attachments

        Issue Links

          Activity

            pzbrawl1937 Peter Brawley added a comment -

            Forgot to mention: the query works in MySQL 8.0.2 dmr.

            pzbrawl1937 Peter Brawley added a comment - Forgot to mention: the query works in MySQL 8.0.2 dmr.

            pzbrawl1937,

            10.2.2 was the first beta, please don't use it for anything important. There have been several releases since then, and many problems have been fixed. This one in particular was fixed in 10.2.6 in scope of MDEV-12440.

            commit 428a922cd0284b5fbdf97f74118209a6a9b4fb4c
            Author: Igor Babaev
            Date:   Thu Apr 6 12:08:14 2017 -0700
             
                Fixed the bug mdev-12440.
                
                When a CTE referring to another CTE from the same with clause
                was used twice then the server could not find the second CTE and
                reported a bogus error message.
                This happened because for any unit that was created as a clone of
                a CTE specification the pointer to the WITH clause that owned this CTE
                was not set.
            

            elenst Elena Stepanova added a comment - pzbrawl1937 , 10.2.2 was the first beta, please don't use it for anything important. There have been several releases since then, and many problems have been fixed. This one in particular was fixed in 10.2.6 in scope of MDEV-12440 . commit 428a922cd0284b5fbdf97f74118209a6a9b4fb4c Author: Igor Babaev Date: Thu Apr 6 12:08:14 2017 -0700   Fixed the bug mdev-12440. When a CTE referring to another CTE from the same with clause was used twice then the server could not find the second CTE and reported a bogus error message. This happened because for any unit that was created as a clone of a CTE specification the pointer to the WITH clause that owned this CTE was not set.
            pzbrawl1937 Peter Brawley added a comment -

            Thx, I can confirm the bug is gone in 10.2.7.

            pzbrawl1937 Peter Brawley added a comment - Thx, I can confirm the bug is gone in 10.2.7.

            People

              Unassigned Unassigned
              pzbrawl1937 Peter Brawley
              Votes:
              0 Vote for this issue
              Watchers:
              3 Start watching this issue

              Dates

                Created:
                Updated:
                Resolved:

                Git Integration

                  Error rendering 'com.xiplink.jira.git.jira_git_plugin:git-issue-webpanel'. Please contact your Jira administrators.