1
0
mirror of https://github.com/postgres/postgres.git synced 2025-12-10 14:22:35 +03:00

Make the behavior of HAVING without GROUP BY conform to the SQL spec.

Formerly, if such a clause contained no aggregate functions we mistakenly
treated it as equivalent to WHERE.  Per spec it must cause the query to
be treated as a grouped query of a single group, the same as appearance
of aggregate functions would do.  Also, the HAVING filter must execute
after aggregate function computation even if it itself contains no
aggregate functions.
This commit is contained in:
Tom Lane
2005-03-10 23:21:26 +00:00
parent 609e32b929
commit 595ed2a855
20 changed files with 385 additions and 238 deletions

View File

@@ -21,7 +21,7 @@ SELECT b, c FROM test_having
3 | bbbb
(2 rows)
-- HAVING is equivalent to WHERE in this case
-- HAVING is effectively equivalent to WHERE in this case
SELECT b, c FROM test_having
GROUP BY b, c HAVING b = 3 ORDER BY b, c;
b | c
@@ -49,4 +49,41 @@ SELECT c, max(a) FROM test_having
bbbb | 5
(2 rows)
-- test degenerate cases involving HAVING without GROUP BY
-- Per SQL spec, these should generate 0 or 1 row, even without aggregates
SELECT min(a), max(a) FROM test_having HAVING min(a) = max(a);
min | max
-----+-----
(0 rows)
SELECT min(a), max(a) FROM test_having HAVING min(a) < max(a);
min | max
-----+-----
0 | 9
(1 row)
-- errors: ungrouped column references
SELECT a FROM test_having HAVING min(a) < max(a);
ERROR: column "test_having.a" must appear in the GROUP BY clause or be used in an aggregate function
SELECT 1 AS one FROM test_having HAVING a > 1;
ERROR: column "test_having.a" must appear in the GROUP BY clause or be used in an aggregate function
-- the really degenerate case: need not scan table at all
SELECT 1 AS one FROM test_having HAVING 1 > 2;
one
-----
(0 rows)
SELECT 1 AS one FROM test_having HAVING 1 < 2;
one
-----
1
(1 row)
-- and just to prove that we aren't scanning the table:
SELECT 1 AS one FROM test_having WHERE 1/a = 1 HAVING 1 < 2;
one
-----
1
(1 row)
DROP TABLE test_having;

View File

@@ -21,7 +21,7 @@ SELECT b, c FROM test_having
3 | bbbb
(2 rows)
-- HAVING is equivalent to WHERE in this case
-- HAVING is effectively equivalent to WHERE in this case
SELECT b, c FROM test_having
GROUP BY b, c HAVING b = 3 ORDER BY b, c;
b | c
@@ -49,4 +49,41 @@ SELECT c, max(a) FROM test_having
XXXX | 0
(2 rows)
-- test degenerate cases involving HAVING without GROUP BY
-- Per SQL spec, these should generate 0 or 1 row, even without aggregates
SELECT min(a), max(a) FROM test_having HAVING min(a) = max(a);
min | max
-----+-----
(0 rows)
SELECT min(a), max(a) FROM test_having HAVING min(a) < max(a);
min | max
-----+-----
0 | 9
(1 row)
-- errors: ungrouped column references
SELECT a FROM test_having HAVING min(a) < max(a);
ERROR: column "test_having.a" must appear in the GROUP BY clause or be used in an aggregate function
SELECT 1 AS one FROM test_having HAVING a > 1;
ERROR: column "test_having.a" must appear in the GROUP BY clause or be used in an aggregate function
-- the really degenerate case: need not scan table at all
SELECT 1 AS one FROM test_having HAVING 1 > 2;
one
-----
(0 rows)
SELECT 1 AS one FROM test_having HAVING 1 < 2;
one
-----
1
(1 row)
-- and just to prove that we aren't scanning the table:
SELECT 1 AS one FROM test_having WHERE 1/a = 1 HAVING 1 < 2;
one
-----
1
(1 row)
DROP TABLE test_having;

View File

@@ -21,7 +21,7 @@ SELECT b, c FROM test_having
3 | bbbb
(2 rows)
-- HAVING is equivalent to WHERE in this case
-- HAVING is effectively equivalent to WHERE in this case
SELECT b, c FROM test_having
GROUP BY b, c HAVING b = 3 ORDER BY b, c;
b | c
@@ -49,4 +49,41 @@ SELECT c, max(a) FROM test_having
XXXX | 0
(2 rows)
-- test degenerate cases involving HAVING without GROUP BY
-- Per SQL spec, these should generate 0 or 1 row, even without aggregates
SELECT min(a), max(a) FROM test_having HAVING min(a) = max(a);
min | max
-----+-----
(0 rows)
SELECT min(a), max(a) FROM test_having HAVING min(a) < max(a);
min | max
-----+-----
0 | 9
(1 row)
-- errors: ungrouped column references
SELECT a FROM test_having HAVING min(a) < max(a);
ERROR: column "test_having.a" must appear in the GROUP BY clause or be used in an aggregate function
SELECT 1 AS one FROM test_having HAVING a > 1;
ERROR: column "test_having.a" must appear in the GROUP BY clause or be used in an aggregate function
-- the really degenerate case: need not scan table at all
SELECT 1 AS one FROM test_having HAVING 1 > 2;
one
-----
(0 rows)
SELECT 1 AS one FROM test_having HAVING 1 < 2;
one
-----
1
(1 row)
-- and just to prove that we aren't scanning the table:
SELECT 1 AS one FROM test_having WHERE 1/a = 1 HAVING 1 < 2;
one
-----
1
(1 row)
DROP TABLE test_having;

View File

@@ -18,7 +18,7 @@ INSERT INTO test_having VALUES (9, 4, 'CCCC', 'j');
SELECT b, c FROM test_having
GROUP BY b, c HAVING count(*) = 1 ORDER BY b, c;
-- HAVING is equivalent to WHERE in this case
-- HAVING is effectively equivalent to WHERE in this case
SELECT b, c FROM test_having
GROUP BY b, c HAVING b = 3 ORDER BY b, c;
@@ -30,4 +30,21 @@ SELECT c, max(a) FROM test_having
GROUP BY c HAVING count(*) > 2 OR min(a) = max(a)
ORDER BY c;
-- test degenerate cases involving HAVING without GROUP BY
-- Per SQL spec, these should generate 0 or 1 row, even without aggregates
SELECT min(a), max(a) FROM test_having HAVING min(a) = max(a);
SELECT min(a), max(a) FROM test_having HAVING min(a) < max(a);
-- errors: ungrouped column references
SELECT a FROM test_having HAVING min(a) < max(a);
SELECT 1 AS one FROM test_having HAVING a > 1;
-- the really degenerate case: need not scan table at all
SELECT 1 AS one FROM test_having HAVING 1 > 2;
SELECT 1 AS one FROM test_having HAVING 1 < 2;
-- and just to prove that we aren't scanning the table:
SELECT 1 AS one FROM test_having WHERE 1/a = 1 HAVING 1 < 2;
DROP TABLE test_having;