Oracle Database 23ai : Group By and Having using Column Aliases


Oracle Database 23ai allows us to use Column Aliases in GROUP BY and HAVING clauses. It also allows us to use Column-position in GROUP BY clause. Let’s see, how.

To demonstrate this enhancement, we will work with the EMP table and the DEPT table.

SQL> SELECT * from emp;

EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
________ _________ ____________ _______ ____________ _______ _______ _________
7369 SMITH CLERK 7902 17-DEC-80 800 20
7499 ALLEN SALESMAN 7698 20-FEB-81 1600 300 30
7521 WARD SALESMAN 7698 22-FEB-81 1250 500 30
7566 JONES MANAGER 7839 02-APR-81 2975 20
7654 MARTIN SALESMAN 7698 28-SEP-81 1250 1400 30
7698 BLAKE MANAGER 7839 01-MAY-81 2850 30
7782 CLARK MANAGER 7839 09-JUN-81 2450 10
7788 SCOTT ANALYST 7566 19-APR-87 3000 20
7839 KING PRESIDENT 17-NOV-81 5000 10
7844 TURNER SALESMAN 7698 08-SEP-81 1500 0 30
7876 ADAMS CLERK 7788 23-MAY-87 1100 20
7900 JAMES CLERK 7698 03-DEC-81 950 30
7902 FORD ANALYST 7566 03-DEC-81 3000 20
7934 MILLER CLERK 7782 23-JAN-82 1300 10


14 rows selected.

Elapsed: 00:00:00.015
SQL> SELECT * FROM dept;

DEPTNO DNAME LOC
_________ _____________ ___________
10 ACCOUNTING NEW YORK
20 RESEARCH DALLAS
30 SALES CHICAGO
40 OPERATIONS BOSTON

Elapsed: 00:00:00.079

GROUP BY using Column Aliases

We have a requirement to display each Department Name in Initcaps and the Average Salary of the employees in each Department.

In any of the releases prior to 23ai, you would have needed to use INITCAP(d.dname) in the GROUP BY clause, and not use the column alias DEPARTMENT_NAME, like below.

SQL> SELECT INITCAP(d.dname) DEPARTMENT_NAME, ROUND(AVG(e.sal),2) AVERAGE_SALARY
FROM emp e, dept d
WHERE e.deptno = d.deptno
GROUP BY INITCAP(d.dname);

DEPARTMENT_NAME AVERAGE_SALARY
__________________ _________________
Accounting 2916.67
Research 2175
Sales 1566.67

Elapsed: 00:00:00.026

However, in 23ai, you’ll be able to use the column alias in the GROUP BY clause instead.

SQL> SELECT INITCAP(d.dname) DEPARTMENT_NAME, ROUND(AVG(e.sal),2) AVERAGE_SALARY
FROM emp e, dept d
WHERE e.deptno = d.deptno
GROUP BY DEPARTMENT_NAME;

DEPARTMENT_NAME AVERAGE_SALARY
__________________ _________________
Accounting 2916.67
Research 2175
Sales 1566.67

Elapsed: 00:00:00.009

HAVING using Column Aliases

Now let’s say, we have a requirement to display the Departments where the average salary > 2000. In previous releases, we would have needed to explicitly use the function with having.

SQL> SELECT INITCAP(d.dname) DEPARTMENT_NAME, ROUND(AVG(e.sal),2) AVERAGE_SALARY
FROM emp e, dept d
WHERE e.deptno = d.deptno
GROUP BY DEPARTMENT_NAME
HAVING ROUND(AVG(e.sal),2) > 2000 ;

DEPARTMENT_NAME AVERAGE_SALARY
__________________ _________________
Accounting 2916.67
Research 2175

23ai will allow you to use the alias name of the column, instead of the complex columns. See below.

SQL> SELECT INITCAP(d.dname) DEPARTMENT_NAME, ROUND(AVG(e.sal),2) AVERAGE_SALARY
FROM emp e, dept d
WHERE e.deptno = d.deptno
GROUP BY DEPARTMENT_NAME
HAVING AVERAGE_SALARY > 2000 ;

DEPARTMENT_NAME AVERAGE_SALARY
__________________ _________________
Accounting 2916.67
Research 2175

Elapsed: 00:00:00.015

GROUP BY using Column Position

Besides, 23ai allows you to use column positions in GROUP BY clause instead of the actual columns. However, you need to set the group_by_position_enable parameter to true. By default it is set to false. I will enable it at the session level.

SQL> ALTER SESSION SET group_by_position_enabled=true;
SQL>
SQL> SELECT INITCAP(d.dname) DEPARTMENT_NAME, ROUND(AVG(e.sal),2) AVERAGE_SALARY
FROM emp e, dept d
WHERE e.deptno = d.deptno
GROUP BY 1
HAVING AVERAGE_SALARY > 2000 ;

DEPARTMENT_NAME AVERAGE_SALARY
__________________ _________________
Accounting 2916.67
Research 2175

References

Leave a comment