搜索
查看: 1548|: 0

【Oracle】Oracle分析函数PERCENTILE_CONT

[复制链接]

191

主题

18

回帖

694

积分

高级会员

积分
694
发表于 2014-11-20 16:55:50 | 显示全部楼层 |阅读模式
查询各部门中薪水分布处于25%、50%、75%位置的人的薪水,percent_rank()是确定排行中的相对位置。
  1. create table EMP
  2. (
  3. EMPNO NUMBER(4) not null,
  4. ENAME VARCHAR2(10),
  5. JOB VARCHAR2(9),
  6. MGR NUMBER(4),
  7. HIREDATE DATE,
  8. SAL NUMBER(7,2),
  9. COMM NUMBER(7,2),
  10. DEPTNO NUMBER(2)
  11. );
  12. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  13. values (7369, 'SMITH', 'CLERK', 7902, to_date('17-12-1980', 'dd-mm-yyyy'), 800.00, null, 20);
  14. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  15. values (7499, 'ALLEN', 'SALESMAN', 7698, to_date('20-02-1981', 'dd-mm-yyyy'), 1600.00, 300.00, 30);
  16. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  17. values (7521, 'WARD', 'SALESMAN', 7698, to_date('22-02-1981', 'dd-mm-yyyy'), 1250.00, 500.00, 30);
  18. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  19. values (7566, 'JONES', 'MANAGER', 7839, to_date('02-04-1981', 'dd-mm-yyyy'), 2975.00, null, 20);
  20. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  21. values (7654, 'MARTIN', 'SALESMAN', 7698, to_date('28-09-1981', 'dd-mm-yyyy'), 1250.00, 1400.00, 30);
  22. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  23. values (7698, 'BLAKE', 'MANAGER', 7839, to_date('01-05-1981', 'dd-mm-yyyy'), 2850.00, null, 30);
  24. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  25. values (7782, 'CLARK', 'MANAGER', 7839, to_date('09-06-1981', 'dd-mm-yyyy'), 2450.00, null, 10);
  26. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  27. values (7788, 'SCOTT', 'ANALYST', 7566, to_date('19-04-1987', 'dd-mm-yyyy'), 3000.00, null, 20);
  28. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  29. values (7839, 'KING', 'PRESIDENT', null, to_date('17-11-1981', 'dd-mm-yyyy'), 5000.00, null, 10);
  30. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  31. values (7844, 'TURNER', 'SALESMAN', 7698, to_date('08-09-1981', 'dd-mm-yyyy'), 1500.00, 0.00, 30);
  32. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  33. values (7876, 'ADAMS', 'CLERK', 7788, to_date('23-05-1987', 'dd-mm-yyyy'), 1100.00, null, 20);
  34. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  35. values (7900, 'JAMES', 'CLERK', 7698, to_date('03-12-1981', 'dd-mm-yyyy'), 950.00, null, 30);
  36. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  37. values (7902, 'FORD', 'ANALYST', 7566, to_date('03-12-1981', 'dd-mm-yyyy'), 3000.00, null, 20);
  38. insert into emp (EMPNO, ENAME, JOB, MGR, HIREDATE, SAL, COMM, DEPTNO)
  39. values (7934, 'MILLER', 'CLERK', 7782, to_date('23-01-1982', 'dd-mm-yyyy'), 1300.00, null, 10);
  40. commit;

  41. SQL> select e.ename,e.sal,e.deptno,

  42. percent_rank() over(partition by deptno order by sal desc) p_rank,
  43. PERCENTILE_CONT(0) within group(order by sal desc)
  44. over(partition by deptno) max_sal ,
  45. PERCENTILE_CONT(0.25) within group(order by sal desc)
  46. over(partition by deptno) max_sal_25,
  47. PERCENTILE_CONT(0.5) within group(order by sal desc)
  48. over(partition by deptno) max_sal_50,
  49. PERCENTILE_CONT(0.75) within group(order by sal desc)
  50. over(partition by deptno) max_sal_75
  51. from emp e;
  52. ENAME SAL DEPTNO P_RANK MAX_SAL MAX_SAL_25 MAX_SAL_50 MAX_SAL_75
  53. ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
  54. KING 5000 10 0 5000 3725 2450 1875
  55. CLARK 2450 10 .5 5000 3725 2450 1875
  56. MILLER 1300 10 1 5000 3725 2450 1875
  57. SCOTT 3000 20 0 3000 3000 2975 1100
  58. FORD 3000 20 0 3000 3000 2975 1100
  59. JONES 2975 20 .5 3000 3000 2975 1100
  60. ADAMS 1100 20 .75 3000 3000 2975 1100
  61. SMITH 800 20 1 3000 3000 2975 1100
  62. BLAKE 2850 30 0 2850 1575 1375 1250
  63. ALLEN 1600 30 .2 2850 1575 1375 1250
  64. TURNER 1500 30 .4 2850 1575 1375 1250
  65. WARD 1250 30 .6 2850 1575 1375 1250
  66. MARTIN 1250 30 .6 2850 1575 1375 1250
  67. JAMES 950 30 1 2850 1575 1375 1250
  68. 已选择14行。


  69. SQL> select e.ename,e.sal,e.deptno,
  70. percent_rank() over(partition by deptno order by sal) p_rank,
  71. PERCENTILE_CONT(0) within group(order by sal)
  72. over(partition by deptno) max_sal ,
  73. PERCENTILE_CONT(0.25) within group(order by sal)
  74. over(partition by deptno) max_sal_25,
  75. PERCENTILE_CONT(0.5) within group(order by sal)
  76. over(partition by deptno) max_sal_50,
  77. PERCENTILE_CONT(0.75) within group(order by sal)
  78. over(partition by deptno) max_sal_75
  79. from emp e;
  80. ENAME SAL DEPTNO P_RANK MAX_SAL MAX_SAL_25 MAX_SAL_50 MAX_SAL_75
  81. ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
  82. MILLER 1300 10 0 1300 1875 2450 3725
  83. CLARK 2450 10 .5 1300 1875 2450 3725
  84. KING 5000 10 1 1300 1875 2450 3725
  85. SMITH 800 20 0 800 1100 2975 3000
  86. ADAMS 1100 20 .25 800 1100 2975 3000
  87. JONES 2975 20 .5 800 1100 2975 3000
  88. SCOTT 3000 20 .75 800 1100 2975 3000
  89. FORD 3000 20 .75 800 1100 2975 3000
  90. JAMES 950 30 0 950 1250 1375 1575
  91. MARTIN 1250 30 .2 950 1250 1375 1575
  92. WARD 1250 30 .2 950 1250 1375 1575
  93. TURNER 1500 30 .6 950 1250 1375 1575
  94. ALLEN 1600 30 .8 950 1250 1375 1575
  95. BLAKE 2850 30 1 950 1250 1375 1575
  96. 已选择14行。
复制代码


您需要登录后才可以回帖 登录 | 立即注册

本版积分规则

大数据中国微信

QQ   

版权所有: Discuz! © 2001-2013 大数据.

GMT+8, 2024-11-15 21:35 , Processed in 0.065761 second(s), 24 queries .

快速回复 返回顶部 返回列表