Details
Description
Given the following, minimal sample:
CREATE SCHEMA A ; |
|
CREATE TABLE A.A ( A BOOLEAN DEFAULT TRUE); |
|
SELECT 1 AS A FROM A.A AS AA HAVING TRUE; |
Summary: No result is returned if a constant without aggregate function is selected and a HAVING clause (with a constant expression like 'TRUE'), without an explicit GROUP BY clause is used on an empty table.
I expect that a single 1 is returned. This is also the behaviour of Postgres and described here (https://stackoverflow.com/a/53238082). The HAVING groups the empty result into a single, but existing group. HAVING doesn't filter this single row, so a single row and result should be returned.
When a explicit GROUP BY is used, or COUNT ( * ) is used additionally, or there exists an entry in the table, a 1 is returned, which is correct.
@Igor In Postgres, this is an error:
In MariaDB 10.4.5, this also returns an empty result set, like the single 1.
Interesting: If I insert some values before, I get these values back:
-- Returns [1, 0, 1]
It seems like HAVING without a GROUP BY is completely 'ignored'. As far as I understand SQL, there should be a implicit grouping when a having occurs.