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

LP:702345 - Empty query with SUM and HAVING, no GROUP BY returns NULL instead of empty result.

Details

    • Bug
    • Status: Closed (View Workflow)
    • Major
    • Resolution: Fixed
    • None
    • None
    • None

    Description

      The following test case (for LP BUG#609121) extracted from subselect_mat.test:

      create table t1 (c1 int);
      create table t2 (c2 int);
      insert into t1 values (1);
      insert into t2 values (2);

      SELECT SUM(c1) c1_sum FROM t1 WHERE c1 IN (SELECT c2 FROM t2) HAVING c1_sum;

      incorrectly produces a NULL instead of an empty result.

      Attachments

        Activity

          Re: Empty query with SUM and HAVING, no GROUP BY returns NULL instead of empty result.
          The bug is present both with MATERIALIZATION and with IN-TO-EXISTS,
          but not with SEMIJOIN:
          set @@optimizer_switch='materialization=on,in_to_exists=on,semijoin=off';
          set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=off';
          set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off';

          timour Timour Katchaounov (Inactive) added a comment - Re: Empty query with SUM and HAVING, no GROUP BY returns NULL instead of empty result. The bug is present both with MATERIALIZATION and with IN-TO-EXISTS, but not with SEMIJOIN: set @@optimizer_switch='materialization=on,in_to_exists=on,semijoin=off'; set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=off'; set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off';

          Re: Empty query with SUM and HAVING, no GROUP BY returns NULL instead of empty result.
          Analysis:
          Close to its end JOIN::optimize() assigns having to tmp_having, and
          sets the having clause to NULL:

          tmp_having= having;
          if (select_options & SELECT_DESCRIBE)

          { error= 0; DBUG_RETURN(0); }

          having= 0;

          At the same time, this query detects an empty result set, and calls
          return_zero_rows(), which must check the HAVING clause by:

          if (having && having->val_int() == 0)
          send_row=0;

          However having has been already set to NULL, so return_zero_rows
          doesn't check the having clause, hence the wrong result.

          Solution:
          There are two ways to solve this problem:
          a) check join->tmp_having in addition to join->having, or
          b) do not set having= 0 in JOIN::optimize.

          timour Timour Katchaounov (Inactive) added a comment - Re: Empty query with SUM and HAVING, no GROUP BY returns NULL instead of empty result. Analysis: Close to its end JOIN::optimize() assigns having to tmp_having, and sets the having clause to NULL: tmp_having= having; if (select_options & SELECT_DESCRIBE) { error= 0; DBUG_RETURN(0); } having= 0; At the same time, this query detects an empty result set, and calls return_zero_rows(), which must check the HAVING clause by: if (having && having->val_int() == 0) send_row=0; However having has been already set to NULL, so return_zero_rows doesn't check the having clause, hence the wrong result. Solution: There are two ways to solve this problem: a) check join->tmp_having in addition to join->having, or b) do not set having= 0 in JOIN::optimize.

          Launchpad bug id: 702345

          ratzpo Rasmus Johansson (Inactive) added a comment - Launchpad bug id: 702345

          People

            timour Timour Katchaounov (Inactive)
            timour Timour Katchaounov (Inactive)
            Votes:
            0 Vote for this issue
            Watchers:
            0 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.