ROLLUP
=======
Extension of Group By Clause, which Provide super aggregate rows.
Ex:-
-----
Query for sum of salaries by department and also display the total salary of all the departments.
Using Set Operator
-------------------
SQL> SELECT DEPTNO,SUM(SAL)
2 FROM
3 EMP GROUP BY DEPTNO
4 UNION
5 SELECT NULL,SUM(SAL)
6 FROM
7 EMP;
DEPTNO SUM(SAL)
---------- ----------
10 7450
20 10875
30 9400
50 1300
29025
Using Inline Views
--------------------
SQL> SELECT DEPTNO,SUM(SAL) DEPTSAL,A.TOTALSAL TOTALSALARY
2 FROM
3 EMP,(SELECT SUM(SAL) TOTALSAL
4 FROM
5 EMP) A
6 GROUP BY DEPTNO,A.TOTALSAL;
DEPTNO DEPTSAL TOTALSALARY
---------- ---------- -----------
10 7450 29025
20 10875
30 9400
50 1300
Using Rollup
-------------
SQL> SELECT DEPTNO,SUM(SAL)
2 FROM
3 EMP
4 GROUP BY ROLLUP(DEPTNO);
DEPTNO SUM(SAL)
---------- ----------
10 7450
20 10875
30 9400
50 1300
29025
SQL> SELECT DECODE(DEPTNO,NULL,'TOTAL_SAL=>',DEPTNO) AS DEPTNO,SUM(SAL)
2 FROM
3 EMP
4 GROUP BY ROLLUP(DEPTNO);
DEPTNO SUM(SAL)
---------------------------------------- ----------
10 7450
20 10875
30 9400
50 1300
TOTAL_SAL=> 29025
Ex:-
----
Query for display sum (salary) year wise as well the total sal.
SQL> SELECT DECODE(TO_CHAR(HIREDATE,'YYYY'),NULL,'TOTAL SALARY =>',TO_CHAR(HIREDATE,'YYYY')) YEAR,SUM(SAL) YEAR_SAL
2 FROM
3 EMP
4 GROUP BY ROLLUP(TO_CHAR(HIREDATE,'YYYY'));
YEAR YEAR_SAL
--------------- ----------
1980 800
1981 22825
1982 1300
1987 4100
TOTAL SALARY => 29025
SQL> BREAK ON TOTALSAL;
SQL> SELECT TO_CHAR(HIREDATE,'YYYY') YEAR,SUM(SAL) YEAR_SAL,A.TOTALSAL
2 FROM
3 EMP,(SELECT SUM(SAL) TOTALSAL
4 FROM
5 EMP) A
6 GROUP BY TO_CHAR(EMP.HIREDATE,'YYYY'),A.TOTALSAL;
YEAR YEAR_SAL TOTALSAL
---- ---------- ----------
1987 4100 29025
1982 1300
1980 800
1981 22825
Ex:-
----
Query for displaying the avg(sal) by dept and job and department avg(sal)
SQL> BREAK ON AVG_SAL_FOR_DEPT_SAL
SQL> SELECT
2 A.DEPTNO,A.JOB,AVG(A.SAL) AVG_SAL_FOR_DEPT_JOB,B.SAL AVG_SAL_FOR_DEPT_SAL
3 FROM
4 EMP A,(SELECT C.DEPTNO,AVG(C.SAL) SAL
5 FROM
6 (
7 SELECT DEPTNO,AVG(SAL) SAL
8 FROM
9 EMP
10 GROUP BY DEPTNO,JOB) C
11 GROUP BY DEPTNO) B
12 WHERE A.DEPTNO=B.DEPTNO
13 GROUP BY A.DEPTNO,A.JOB,B.SAL
14 /
DEPTNO JOB AVG_SAL_FOR_DEPT_JOB AVG_SAL_FOR_DEPT_SAL
---------- --------- -------------------- ----------------
30 SALESMAN 1400 1733.33333
30 MANAGER 2850
30 CLERK 950
20 MANAGER 2975 2308.33333
10 MANAGER 2450 3725
20 ANALYST 3000 2308.33333
20 CLERK 950
50 CLERK 1300 1300
10 PRESIDENT 5000 3725
Using ROLLUP:-
-------------------
SQL> SELECT DEPTNO,JOB,AVG(SAL)
2 FROM
3 EMP
4 GROUP BY ROLLUP(DEPTNO,JOB);
DEPTNO JOB AVG(SAL)
---------- --------- ----------
10 MANAGER 2450 => Select deptno,job,avg(sal) from emp group by deptno,job;
10 PRESIDENT 5000
10 3725
20 CLERK 950
20 ANALYST 3000
20 MANAGER 2975
20 2175
30 CLERK 950
30 MANAGER 2850
30 SALESMAN 1400
30 1566.66667 => Select deptno,avg(sal) from emp group by deptno;
50 CLERK 1300
50 1300
2073.21429 => Select avg(sal) from emp;
However, this is the wrong approach to reach out the above result using Rollup.
Here is the way to go.
SQL> SELECT DEPTNO,JOB,AVG(AVG_SAL)
2 FROM
3 (
4 SELECT DEPTNO,DECODE(JOB,NULL,'SUB',JOB) AS JOB,AVG(SAL) AVG_SAL
5 FROM
6 EMP
7 GROUP BY ROLLUP(DEPTNO,JOB) HAVING JOB!='SUB'
8 )
9 GROUP BY ROLLUP(DEPTNO,JOB);
DEPTNO JOB AVG(AVG_SAL)
---------- --------- ------------
10 MANAGER 2450
10 PRESIDENT 5000
10 3725
20 CLERK 950
20 ANALYST 3000
20 MANAGER 2975
20 2308.33333
30 CLERK 950
30 MANAGER 2850
30 SALESMAN 1400
30 1733.33333
50 CLERK 1300
50 1300
2319.44444
Then what about ROLLUP(DEPTNO),JOB?
----------------------------------------------
SQL> SELECT DEPTNO,JOB,AVG(SAL)
2 FROM
3 EMP
4 GROUP BY ROLLUP(DEPTNO),JOB ORDER BY DEPTNO;
DEPTNO JOB AVG(SAL)
---------- --------- ----------
10 MANAGER 2450 => SELECT DEPTNO,JOB,AVG(SAL) FROM EMP GROUP BY DEPTNO,JOB;
10 PRESIDENT 5000
20 MANAGER 2975
20 CLERK 950
20 ANALYST 3000
30 MANAGER 2850
30 CLERK 950
30 SALESMAN 1400
50 CLERK 1300
CLERK 1037.5 => SELECT JOB,AVG(SAL) FROM EMP GROUP BY JOB;
SALESMAN 1400
PRESIDENT 5000
ANALYST 3000
MANAGER 2758.33333
DEPTNO,ROLLUP(JOB)?
---------------------------
SQL> SELECT DEPTNO,JOB,AVG(SAL)
2 FROM
3 EMP
4 GROUP BY DEPTNO,ROLLUP(JOB) ORDER BY DEPTNO; Similar to ROLLUP(DEPTNO,JOB)
DEPTNO JOB AVG(SAL)
---------- --------- ----------
10 MANAGER 2450 => SELECT DEPTNO,JOB,AVG(SAL) FROM EMP GROUP BY DEPTNO,JOB;
10 PRESIDENT 5000
10 3725 => SELECT DEPTNO,AVG(SAL) FROM EMP GROUP BY DEPTNO.
20 ANALYST 3000
20 CLERK 950
20 MANAGER 2975
20 2175
30 CLERK 950
30 MANAGER 2850
30 SALESMAN 1400
30 1566.66667
50 CLERK 1300
50 1300
ROLLUP(arg1,arg2,arg3)
-----------------------------
1. Group by arg1,arg2,arg3 and aggregate function
2. Group by arg1,arg2 and aggregate function
3. Group by arg1 and aggregate function
4. Only the aggregate.
=======
Extension of Group By Clause, which Provide super aggregate rows.
Ex:-
-----
Query for sum of salaries by department and also display the total salary of all the departments.
Using Set Operator
-------------------
SQL> SELECT DEPTNO,SUM(SAL)
2 FROM
3 EMP GROUP BY DEPTNO
4 UNION
5 SELECT NULL,SUM(SAL)
6 FROM
7 EMP;
DEPTNO SUM(SAL)
---------- ----------
10 7450
20 10875
30 9400
50 1300
29025
Using Inline Views
--------------------
SQL> SELECT DEPTNO,SUM(SAL) DEPTSAL,A.TOTALSAL TOTALSALARY
2 FROM
3 EMP,(SELECT SUM(SAL) TOTALSAL
4 FROM
5 EMP) A
6 GROUP BY DEPTNO,A.TOTALSAL;
DEPTNO DEPTSAL TOTALSALARY
---------- ---------- -----------
10 7450 29025
20 10875
30 9400
50 1300
Using Rollup
-------------
SQL> SELECT DEPTNO,SUM(SAL)
2 FROM
3 EMP
4 GROUP BY ROLLUP(DEPTNO);
DEPTNO SUM(SAL)
---------- ----------
10 7450
20 10875
30 9400
50 1300
29025
SQL> SELECT DECODE(DEPTNO,NULL,'TOTAL_SAL=>',DEPTNO) AS DEPTNO,SUM(SAL)
2 FROM
3 EMP
4 GROUP BY ROLLUP(DEPTNO);
DEPTNO SUM(SAL)
---------------------------------------- ----------
10 7450
20 10875
30 9400
50 1300
TOTAL_SAL=> 29025
Ex:-
----
Query for display sum (salary) year wise as well the total sal.
SQL> SELECT DECODE(TO_CHAR(HIREDATE,'YYYY'),NULL,'TOTAL SALARY =>',TO_CHAR(HIREDATE,'YYYY')) YEAR,SUM(SAL) YEAR_SAL
2 FROM
3 EMP
4 GROUP BY ROLLUP(TO_CHAR(HIREDATE,'YYYY'));
YEAR YEAR_SAL
--------------- ----------
1980 800
1981 22825
1982 1300
1987 4100
TOTAL SALARY => 29025
SQL> BREAK ON TOTALSAL;
SQL> SELECT TO_CHAR(HIREDATE,'YYYY') YEAR,SUM(SAL) YEAR_SAL,A.TOTALSAL
2 FROM
3 EMP,(SELECT SUM(SAL) TOTALSAL
4 FROM
5 EMP) A
6 GROUP BY TO_CHAR(EMP.HIREDATE,'YYYY'),A.TOTALSAL;
YEAR YEAR_SAL TOTALSAL
---- ---------- ----------
1987 4100 29025
1982 1300
1980 800
1981 22825
Ex:-
----
Query for displaying the avg(sal) by dept and job and department avg(sal)
SQL> BREAK ON AVG_SAL_FOR_DEPT_SAL
SQL> SELECT
2 A.DEPTNO,A.JOB,AVG(A.SAL) AVG_SAL_FOR_DEPT_JOB,B.SAL AVG_SAL_FOR_DEPT_SAL
3 FROM
4 EMP A,(SELECT C.DEPTNO,AVG(C.SAL) SAL
5 FROM
6 (
7 SELECT DEPTNO,AVG(SAL) SAL
8 FROM
9 EMP
10 GROUP BY DEPTNO,JOB) C
11 GROUP BY DEPTNO) B
12 WHERE A.DEPTNO=B.DEPTNO
13 GROUP BY A.DEPTNO,A.JOB,B.SAL
14 /
DEPTNO JOB AVG_SAL_FOR_DEPT_JOB AVG_SAL_FOR_DEPT_SAL
---------- --------- -------------------- ----------------
30 SALESMAN 1400 1733.33333
30 MANAGER 2850
30 CLERK 950
20 MANAGER 2975 2308.33333
10 MANAGER 2450 3725
20 ANALYST 3000 2308.33333
20 CLERK 950
50 CLERK 1300 1300
10 PRESIDENT 5000 3725
Using ROLLUP:-
-------------------
SQL> SELECT DEPTNO,JOB,AVG(SAL)
2 FROM
3 EMP
4 GROUP BY ROLLUP(DEPTNO,JOB);
DEPTNO JOB AVG(SAL)
---------- --------- ----------
10 MANAGER 2450 => Select deptno,job,avg(sal) from emp group by deptno,job;
10 PRESIDENT 5000
10 3725
20 CLERK 950
20 ANALYST 3000
20 MANAGER 2975
20 2175
30 CLERK 950
30 MANAGER 2850
30 SALESMAN 1400
30 1566.66667 => Select deptno,avg(sal) from emp group by deptno;
50 CLERK 1300
50 1300
2073.21429 => Select avg(sal) from emp;
However, this is the wrong approach to reach out the above result using Rollup.
Here is the way to go.
SQL> SELECT DEPTNO,JOB,AVG(AVG_SAL)
2 FROM
3 (
4 SELECT DEPTNO,DECODE(JOB,NULL,'SUB',JOB) AS JOB,AVG(SAL) AVG_SAL
5 FROM
6 EMP
7 GROUP BY ROLLUP(DEPTNO,JOB) HAVING JOB!='SUB'
8 )
9 GROUP BY ROLLUP(DEPTNO,JOB);
DEPTNO JOB AVG(AVG_SAL)
---------- --------- ------------
10 MANAGER 2450
10 PRESIDENT 5000
10 3725
20 CLERK 950
20 ANALYST 3000
20 MANAGER 2975
20 2308.33333
30 CLERK 950
30 MANAGER 2850
30 SALESMAN 1400
30 1733.33333
50 CLERK 1300
50 1300
2319.44444
Then what about ROLLUP(DEPTNO),JOB?
----------------------------------------------
SQL> SELECT DEPTNO,JOB,AVG(SAL)
2 FROM
3 EMP
4 GROUP BY ROLLUP(DEPTNO),JOB ORDER BY DEPTNO;
DEPTNO JOB AVG(SAL)
---------- --------- ----------
10 MANAGER 2450 => SELECT DEPTNO,JOB,AVG(SAL) FROM EMP GROUP BY DEPTNO,JOB;
10 PRESIDENT 5000
20 MANAGER 2975
20 CLERK 950
20 ANALYST 3000
30 MANAGER 2850
30 CLERK 950
30 SALESMAN 1400
50 CLERK 1300
CLERK 1037.5 => SELECT JOB,AVG(SAL) FROM EMP GROUP BY JOB;
SALESMAN 1400
PRESIDENT 5000
ANALYST 3000
MANAGER 2758.33333
DEPTNO,ROLLUP(JOB)?
---------------------------
SQL> SELECT DEPTNO,JOB,AVG(SAL)
2 FROM
3 EMP
4 GROUP BY DEPTNO,ROLLUP(JOB) ORDER BY DEPTNO; Similar to ROLLUP(DEPTNO,JOB)
DEPTNO JOB AVG(SAL)
---------- --------- ----------
10 MANAGER 2450 => SELECT DEPTNO,JOB,AVG(SAL) FROM EMP GROUP BY DEPTNO,JOB;
10 PRESIDENT 5000
10 3725 => SELECT DEPTNO,AVG(SAL) FROM EMP GROUP BY DEPTNO.
20 ANALYST 3000
20 CLERK 950
20 MANAGER 2975
20 2175
30 CLERK 950
30 MANAGER 2850
30 SALESMAN 1400
30 1566.66667
50 CLERK 1300
50 1300
ROLLUP(arg1,arg2,arg3)
-----------------------------
1. Group by arg1,arg2,arg3 and aggregate function
2. Group by arg1,arg2 and aggregate function
3. Group by arg1 and aggregate function
4. Only the aggregate.
Thiripal: Very good blog.It is very useful for people who want become proficient in oracle and postgreSQL.
ReplyDelete