Example: Specifying a GROUP BY Clause on Nonaggregate Expressions When the Select List Includes an Aggregate - Analytics Database - Teradata Vantage

SQL Data Manipulation Language

Deployment
VantageCloud
VantageCore
Edition
Enterprise
IntelliFlex
VMware
Product
Analytics Database
Teradata Vantage
Release Number
17.20
Published
June 2022
Language
English (United States)
Last Update
2024-12-13
dita:mapPath
pon1628111750298.ditamap
dita:ditavalPath
qkf1628213546010.ditaval
dita:id
esx1472246586715
lifecycle
latest
Product Category
Teradata Vantageā„¢

If you specify an aggregate in the select expression list of a query, then you must also specify a GROUP BY clause that includes all nonaggregate expressions from the select list. Otherwise, the system returns the following message.

     Selected non-aggregate values must be part of the associated group.

The system returns error message 3504 whenever an aggregate query includes a nonaggregate expression in its SELECT list, WHERE clause, ORDER BY clause, or HAVING clause, but not in a GROUP BY clause.

The system also returns this error when ORDER BY and WITH clauses specify aggregates, but the select list for the query does not.

For example, the database aborts the following query because it does not specify a GROUP BY clause that groups on the only nonaggregate expression in the select list, which is department_number:

     SELECT department_number, SUM(salary_amount)
     FROM employee
     WHERE department_number IN (100, 200, 300);

To work as intended, the query must be rewritten with an appropriate GROUP BY clause:

     SELECT department_number, SUM(salary_amount)
     FROM employee
     WHERE department_number IN (100, 200, 300)
     GROUP BY department_number;

The following statement aborts and returns an error because it does not specify all of the nonaggregate columns from the select list in its GROUP BY clause.

     SELECT employee.dept_no, department.dept_name, AVG(salary)
     FROM employee, department
     WHERE employee.dept_no = department.dept_no
     GROUP BY employee.dept_no;

In this case, the qualified nonaggregate column department.dept_name is missing from the GROUP BY clause.

The following statement aborts and returns an error because the nonaggregate grouping column specified in the ORDER BY clause is not also specified in the GROUP BY clause.

     SELECT employee.dept_no, AVG(salary)
     FROM employee, department
     WHERE employee.dept_no = department.dept_no
     ORDER BY department.dept_name
     GROUP BY employee.dept_no;

The following statement, based on the table definitions shown, aborts and returns an error because the aggregate query includes a nonaggregate expression, d1, in its HAVING clause, but not in the GROUP BY clause.

     CREATE TABLE t1(a1 int, b1 int, c1 int, d1 int);
     CREATE TABLE t2(a2 int, b2 int, c2 int, d2 int);
     SELECT min(a1) as i, max(b1) as j from t1
     GROUP BY c1
     HAVING 30 >= (sel count(*) from t2 where t1.d1=5);

The correct form of the query includes the nonaggregate expression, d1, in its HAVING clause and in the GROUP BY clause.

     SELECT min(a1) as i, max(b1) as j from t1
     GROUP BY c1, d1
     HAVING 30 >= (sel count(*) from t2 where t1.d1=5);