Grouping_Id Concept in SQL with Group by Extension Cube and Rollup
Grouping_ID Concept with
Cube and Rollup
Row
Labels
|
Sum of
SAL
|
|
Rollup_ID
|
|
CUBE_ID
|
|
ANALYST
|
6000
|
Rollup
|
1
|
Cube
|
1
|
Job Wise
Total
|
20
|
6000
|
|
0
|
|
0
|
|
CLERK
|
2850
|
Rollup
|
1
|
Cube
|
1
|
Job Wise
Total
|
20
|
1900
|
|
0
|
|
0
|
|
30
|
950
|
|
0
|
|
0
|
|
MANAGER
|
8275
|
Rollup
|
1
|
Cube
|
1
|
Job Wise
Total
|
10
|
2450
|
|
0
|
|
0
|
|
20
|
2975
|
|
0
|
|
0
|
|
30
|
2850
|
|
0
|
|
0
|
|
PRESIDENT
|
5000
|
Rollup
|
1
|
Cube
|
1
|
Job Wise
Total
|
10
|
5000
|
|
0
|
|
0
|
|
SALESMAN
|
5600
|
Rollup
|
1
|
Cube
|
1
|
Job Wise
Total
|
30
|
5600
|
|
0
|
|
0
|
|
Grand
Total
|
27725
|
Rollup
|
3
|
Cube
|
3
|
Grand
Total
|
10
|
7450
|
|
|
Cube
|
2
|
Dept
wise Total
|
20
|
10875
|
|
|
Cube
|
2
|
Dept
wise Total
|
30
|
9400
|
|
|
Cube
|
2
|
Dept
wise Total
|
--====================================================
select * from XX_EMP_TL
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
|
09-Dec-82
|
3000
|
|
20
|
7839
|
KING
|
PRESIDENT
|
|
17-Nov-81
|
5000
|
|
10
|
7844
|
TURNER
|
SALESMAN
|
7698
|
08-Sep-81
|
1500
|
0
|
30
|
7876
|
ADAMS
|
CLERK
|
7788
|
12-Jan-83
|
1100
|
|
20
|
7900
|
JAMES
|
CLERK
|
7698
|
03-Dec-81
|
950
|
|
30
|
7902
|
FORD
|
ANALYST
|
7566
|
03-Dec-81
|
3000
|
|
20
|
--====================================================
select DEPTNO, SUM(SAL)
Salary
from XX_EMP_TL
GROUP BY DEPTNO
DEPTNO
|
SALARY
|
30
|
9400
|
20
|
10875
|
10
|
7450
|
select
DEPTNO , SUM(SAL)
SAL
from XX_EMP_TL
GROUP BY ROLLUP(DEPTNO)
order by 1
DEPTNO
|
SAL
|
10
|
7450
|
20
|
10875
|
30
|
9400
|
|
27725
|
select
DEPTNO , SUM(SAL)
SAL
from XX_EMP_TL
GROUP BY CUBE(DEPTNO)
order by 1
DEPTNO
|
SAL
|
10
|
7450
|
20
|
10875
|
30
|
9400
|
|
27725
|
select DEPTNO, SUM(SAL) SAL , GROUPING_ID(DEPTNO)
from XX_EMP_TL
GROUP BY ROLLUP(DEPTNO)
order by 1
DEPTNO
|
SAL
|
GROUPING_ID(DEPTNO)
|
10
|
7450
|
0
|
20
|
10875
|
0
|
30
|
9400
|
0
|
|
27725
|
1
|
select DEPTNO, SUM(SAL) SAL, DECODE(GROUPING_ID(DEPTNO), 1, 'Grand
Total' , '')
TOTAL
from XX_EMP_TL
GROUP BY ROLLUP(DEPTNO)
order by 1
DEPTNO
|
SAL
|
TOTAL
|
10
|
7450
|
|
20
|
10875
|
|
30
|
9400
|
|
|
27725
|
Grand
Total
|
--===============with
2 Columns ==========================
select JOB,
DEPTNO, SUM(SAL)
Salary
from XX_EMP_TL
GROUP BY JOB,
DEPTNO
order by 1
JOB
|
DEPTNO
|
SALARY
|
ANALYST
|
20
|
6000
|
CLERK
|
20
|
1900
|
CLERK
|
30
|
950
|
MANAGER
|
10
|
2450
|
MANAGER
|
20
|
2975
|
MANAGER
|
30
|
2850
|
PRESIDENT
|
10
|
5000
|
SALESMAN
|
30
|
5600
|
--============
ROLLUP=============
select NVL(JOB,'TOTAL') JOB,
NVL(TO_CHAR(DEPTNO),'TOTAL')
DEPTNO,
SUM(SAL) SAL ,
GROUPING_ID(JOB,
DEPTNO)
from XX_EMP_TL
GROUP BY ROLLUP(JOB,
DEPTNO)
order by 1,2
JOB
|
DEPTNO
|
SAL
|
GROUPING_ID(JOB,DEPTNO)
|
ANALYST
|
20
|
6000
|
0
|
ANALYST
|
TOTAL
|
6000
|
1
|
CLERK
|
20
|
1900
|
0
|
CLERK
|
30
|
950
|
0
|
CLERK
|
TOTAL
|
2850
|
1
|
MANAGER
|
10
|
2450
|
0
|
MANAGER
|
20
|
2975
|
0
|
MANAGER
|
30
|
2850
|
0
|
MANAGER
|
TOTAL
|
8275
|
1
|
PRESIDENT
|
10
|
5000
|
0
|
PRESIDENT
|
TOTAL
|
5000
|
1
|
SALESMAN
|
30
|
5600
|
0
|
SALESMAN
|
TOTAL
|
5600
|
1
|
TOTAL
|
TOTAL
|
27725
|
3
|
select
NVL(JOB,'TOTAL') JOB, NVL(TO_CHAR(DEPTNO),'TOTAL')
DEPTNO, SUM(SAL) SAL , GROUPING_ID(JOB,
DEPTNO) ID,
DECODE(GROUPING_ID(JOB,
DEPTNO),1, 'Job
wise Salary ', 2, 'Dept
Wise Salary' ,3, 'Grand
Total', '')
TOTAL
from XX_EMP_TL
GROUP BY ROLLUP(JOB,
DEPTNO)
order by 1,2
JOB
|
DEPTNO
|
SAL
|
ID
|
TOTAL
|
ANALYST
|
20
|
6000
|
0
|
|
ANALYST
|
TOTAL
|
6000
|
1
|
Job wise
Salary
|
CLERK
|
20
|
1900
|
0
|
|
CLERK
|
30
|
950
|
0
|
|
CLERK
|
TOTAL
|
2850
|
1
|
Job wise
Salary
|
MANAGER
|
10
|
2450
|
0
|
|
MANAGER
|
20
|
2975
|
0
|
|
MANAGER
|
30
|
2850
|
0
|
|
MANAGER
|
TOTAL
|
8275
|
1
|
Job wise
Salary
|
PRESIDENT
|
10
|
5000
|
0
|
|
PRESIDENT
|
TOTAL
|
5000
|
1
|
Job wise
Salary
|
SALESMAN
|
30
|
5600
|
0
|
|
SALESMAN
|
TOTAL
|
5600
|
1
|
Job wise
Salary
|
TOTAL
|
TOTAL
|
27725
|
3
|
Grand
Total
|
--============
CUBE =============
select NVL(JOB,'TOTAL') JOB,
NVL(TO_CHAR(DEPTNO),'TOTAL')
DEPTNO,
SUM(SAL) SAL ,
GROUPING_ID(JOB,
DEPTNO)
from XX_EMP_TL
GROUP BY CUBE(JOB,
DEPTNO)
order by 1,2
JOB
|
DEPTNO
|
SAL
|
GROUPING_ID(JOB,DEPTNO)
|
ANALYST
|
20
|
6000
|
0
|
ANALYST
|
TOTAL
|
6000
|
1
|
CLERK
|
20
|
1900
|
0
|
CLERK
|
30
|
950
|
0
|
CLERK
|
TOTAL
|
2850
|
1
|
MANAGER
|
10
|
2450
|
0
|
MANAGER
|
20
|
2975
|
0
|
MANAGER
|
30
|
2850
|
0
|
MANAGER
|
TOTAL
|
8275
|
1
|
PRESIDENT
|
10
|
5000
|
0
|
PRESIDENT
|
TOTAL
|
5000
|
1
|
SALESMAN
|
30
|
5600
|
0
|
SALESMAN
|
TOTAL
|
5600
|
1
|
TOTAL
|
10
|
7450
|
2
|
TOTAL
|
20
|
10875
|
2
|
TOTAL
|
30
|
9400
|
2
|
TOTAL
|
TOTAL
|
27725
|
3
|
select --NVL(TO_CHAR(MGR),'TOTAL')
MGR,
NVL(JOB,'TOTAL') JOB, NVL(TO_CHAR(DEPTNO),'TOTAL')
DEPTNO, SUM(SAL) SAL , GROUPING_ID(JOB,
DEPTNO) ID,
DECODE(GROUPING_ID(JOB,
DEPTNO),1, 'Job
wise Salary ', 2, 'Dept
Wise Salary' ,3, 'Grand
Total', '')
TOTAL
from XX_EMP_TL
GROUP BY CUBE(JOB,
DEPTNO)
order by 1,2
JOB
|
DEPTNO
|
SAL
|
ID
|
TOTAL
|
ANALYST
|
20
|
6000
|
0
|
|
ANALYST
|
TOTAL
|
6000
|
1
|
Job wise
Salary
|
CLERK
|
20
|
1900
|
0
|
|
CLERK
|
30
|
950
|
0
|
|
CLERK
|
TOTAL
|
2850
|
1
|
Job wise
Salary
|
MANAGER
|
10
|
2450
|
0
|
|
MANAGER
|
20
|
2975
|
0
|
|
MANAGER
|
30
|
2850
|
0
|
|
MANAGER
|
TOTAL
|
8275
|
1
|
Job wise
Salary
|
PRESIDENT
|
10
|
5000
|
0
|
|
PRESIDENT
|
TOTAL
|
5000
|
1
|
Job wise
Salary
|
SALESMAN
|
30
|
5600
|
0
|
|
SALESMAN
|
TOTAL
|
5600
|
1
|
Job wise
Salary
|
TOTAL
|
10
|
7450
|
2
|
Dept
Wise Salary
|
TOTAL
|
20
|
10875
|
2
|
Dept
Wise Salary
|
TOTAL
|
30
|
9400
|
2
|
Dept
Wise Salary
|
TOTAL
|
TOTAL
|
27725
|
3
|
Grand
Total
|
select * from (
select --NVL(TO_CHAR(MGR),'TOTAL')
MGR,
NVL(JOB,'TOTAL') JOB, NVL(TO_CHAR(DEPTNO),'TOTAL')
DEPTNO, SUM(SAL) SAL from XX_EMP_TL
GROUP BY CUBE(JOB,
DEPTNO)
)
PIVOT (SUM(SAL) AS
SALARY FOR (DEPTNO) IN (
'10' AS "10"
, '20' AS "20"
, '30' AS "30"
, 'TOTAL'
TOTAL
) )
ORDER BY 1
JOB
|
10_SALARY
|
20_SALARY
|
30_SALARY
|
TOTAL_SALARY
|
ANALYST
|
|
6000
|
|
6000
|
CLERK
|
|
1900
|
950
|
2850
|
MANAGER
|
2450
|
2975
|
2850
|
8275
|
PRESIDENT
|
5000
|
|
|
5000
|
SALESMAN
|
|
|
5600
|
5600
|
TOTAL
|
7450
|
10875
|
9400
|
27725
|
--===============with
3 Columns ==========================
select MGR, JOB,
DEPTNO, SUM(SAL)
Salary
from XX_EMP_TL
GROUP BY MGR, JOB,
DEPTNO
select NVL(TO_CHAR(MGR),'TOTAL')
MGR, NVL(JOB,'Sub
Total') JOB, NVL(TO_CHAR(DEPTNO),'TOTAL')
DEPTNO, SUM(SAL) SAL,GROUPING_ID(MGR,JOB,
DEPTNO) ,
DECODE(GROUPING_ID(MGR,JOB,
DEPTNO),1, 'DEPT
Wise Salary' ,2, 'JOB
wise Salary ', 3, 'MGR
Wise Salary' ,4, 'Grand
Total',5,'JOB
wise Total', 6,'DEPT
wise TOTAL',7,'MGR
wise TOTAL', '')
TOTAL
from XX_EMP_TL
GROUP BY CUBE(MGR,JOB,
DEPTNO)
order by 5
select * from (
select NVL(TO_CHAR(MGR),'TOTAL')
MGR, NVL(JOB,'Sub
Total') JOB, NVL(TO_CHAR(DEPTNO),'TOTAL')
DEPTNO, SUM(SAL) SAL from XX_EMP_TL
GROUP BY CUBE(MGR,JOB,
DEPTNO)
)
PIVOT (SUM(SAL) AS
SALARY FOR (DEPTNO) IN (
'10' AS "10"
, '20' AS "20"
, '30' AS "30"
, 'TOTAL'
TOTAL
) )
ORDER by 1,2
--=================
select * from (
select NVL(TO_CHAR(MGR),'TOTAL')
MGR, NVL(JOB,'Sub
Total') JOB, NVL(TO_CHAR(DEPTNO),'TOTAL')
DEPTNO, SUM(SAL) SAL from XX_EMP_TL
GROUP BY CUBE(MGR,JOB,
DEPTNO)
)
PIVOT (SUM(SAL) AS SALARY
FOR (DEPTNO) IN (
'10' AS "10"
, '20' AS "20"
, '30' AS "30"
, 'TOTAL'
TOTAL
) )
MINUS
select * from (
select * from (
select NVL(TO_CHAR(MGR),'TOTAL')
MGR, NVL(JOB,'Sub
Total') JOB, NVL(TO_CHAR(DEPTNO),'TOTAL')
DEPTNO, SUM(SAL) SAL from XX_EMP_TL
GROUP BY CUBE(MGR,JOB,
DEPTNO)
)
PIVOT (SUM(SAL) AS
SALARY FOR (DEPTNO) IN (
'10' AS "10"
, '20' AS "20"
, '30' AS "30"
, 'TOTAL'
TOTAL
) )
ORDER BY 1,2
) A where MGR = 'TOTAL'
AND JOB in ('ANALYST','CLERK','MANAGER','PRESIDENT','SALESMAN')
Comments
Post a Comment