分类: Oracle
2008-04-16 14:05:19
Oracle从8.1.6开始提供分析函数,分析函数用于计算基于组的某种聚合值,它和聚合函数的不同之处是对于每个组返回多行,而聚合函数对于每个组只返回一行。下面例子中使用的表来自Oracle自带的HR用户下的表,如果没有安装该用户,可以在SYS用户下运行$ORACLE_HOME/demo/schema/human_resources/hr_main.sql来创建。少数几个例子需要访问SH用户下的表,如果没有安装该用户,可以在SYS用户下运行$ORACLE_HOME/demo/schema/sales_history/sh_main.sql来创建。如果未指明缺省是在HR用户下运行例子。
开窗函数的的理解:开窗函数指定了分析函数工作的数据窗口大小,这个数据窗口大小可能会随着行的变化而变化,举例如下:over(order by salary) 按照salary排序进行累计,order by是个默认的开窗函数,over(partition by deptno)按照部门分区,over(order by salary range between 50 preceding and 150 following)每行对应的数据窗口是之前行幅度值不超过50,之后行幅度值不超过150,over(order by salary rows between 50 preceding and 150 following)每行对应的数据窗口是之前50行,之后150行over(order by salary rows between unbounded preceding and unbounded following)每行对应的数据窗口是从第一行到最后一行,等效:over(order by salary range between unbounded preceding and unbounded following)主要参考资料:《expert one-on-one》 Tom Kyte 《Oracle9i SQL Reference》第6章
AVG 功能描述:用于计算一个组和数据窗口内表达式的平均值。
SAMPLE:下面的例子中列c_mavg计算员工表中每个员工的平均薪水报告,该平均值由当前员工和与之具有相同经理的前一个和后一个三者的平均数得来;
SELECT manager_id, last_name, hire_date, salary, AVG(salary) OVER (PARTITION BY manager_id ORDER BY hire_date ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING) AS c_mavg FROM employees;MANAGER_ID LAST_NAME HIRE_DATE SALARY C_MAVG---------- ------------------------- --------- ---------- ---------- 100 Kochhar 21-SEP-89 17000 17000 100 De Haan 13-JAN-93 17000 15000 100 Raphaely 07-DEC-94 11000 11966.6667 100 Kaufling 01-MAY-95 7900 10633.3333 100 Hartstein 17-FEB-96 13000 9633.33333 100 Weiss 18-JUL-96 8000 11666.6667 100 Russell 01-OCT-96 14000 11833.3333...
CORR 功能描述:返回一对表达式的相关系数,它是如下的缩写: COVAR_POP(expr1,expr2)/STDDEV_POP(expr1)*STDDEV_POP(expr2)) 从统计上讲,相关性是变量之间关联的强度,变量之间的关联意味着在某种程度 上一个变量的值可由其它的值进行预测。通过返回一个-1~1之间的一个数, 相关 系数给出了关联的强度,0表示不相关。
SAMPLE:下例返回1998年月销售收入和月单位销售的关系的累积系数(本例在SH用户下运行)
SELECT t.calendar_month_number, CORR (SUM(s.amount_sold), SUM(s.quantity_sold)) OVER (ORDER BY t.calendar_month_number) as CUM_CORR FROM sales s, times t
WHERE s.time_id = t.time_id AND calendar_year = 1998
GROUP BY t.calendar_month_number
ORDER BY t.calendar_month_number;
CALENDAR_MONTH_NUMBER CUM_CORR
-------------------------------
1 2 1 3 .994309382 4 .852040875 5 .846652204 6 .871250628 7 .910029803 8 .917556399 9 .920154356 10 .86720251 11 .844864765 12 .903542662
COVAR_POP 功能描述:返回一对表达式的总体协方差。SAMPLE:下例CUM_COVP返回定价和最小产品价格的累积总体协方差
SELECT product_id, supplier_id, COVAR_POP(list_price, min_price) OVER (ORDER BY product_id, supplier_id) AS CUM_COVP, COVAR_SAMP(list_price, min_price) OVER (ORDER BY product_id, supplier_id) AS CUM_COVS FROM product_information pWHERE category_id = 29ORDER BY product_id, supplier_id;
PRODUCT_ID SUPPLIER_ID CUM_COVP CUM_COVS
---------- ----------- ---------- ---------- 1774 103088 0 1775 103087 1473.25 2946.5 1794 103096 1702.77778 2554.16667 1825 103093 1926.25 2568.33333 2004 103086 1591.4 1989.25 2005 103086 1512.5 1815 2416 103088 1475.97959 1721.97619..
COVAR_SAMP 功能描述:返回一对表达式的样本协方差。SAMPLE:下例CUM_COVS返回定价和最小产品价格的累积样本协方差SELECT product_id, supplier_id, COVAR_POP(list_price, min_price) OVER (ORDER BY product_id, supplier_id) AS CUM_COVP, COVAR_SAMP(list_price, min_price) OVER (ORDER BY product_id, supplier_id) AS CUM_COVS FROM product_information pWHERE category_id = 29ORDER BY product_id, supplier_id;PRODUCT_ID SUPPLIER_ID CUM_COVP CUM_COVS---------- ----------- ---------- ---------- 1774 103088 0 1775 103087 1473.25 2946.5 1794 103096 1702.77778 2554.16667 1825 103093 1926.25 2568.33333 2004 103086 1591.4 1989.25 2005 103086 1512.5 1815 2416 103088 1475.97959 1721.97619..
COUNT 功能描述:对一组内发生的事情进行累积计数,如果指定*或一些非空常数,count将对所有行计数,如果指定一个表达式,count返回表达式非空赋值的计数,当有相同值出现时,这些相等的值都会被纳入被计算的值;可以使用DISTINCT来记录去掉一组中完全相同的数据后出现的行数。
SAMPLE:下面例子中计算每个员工在按薪水排序中当前行附近薪水在[n-50,n+150]之间的行数,n表示当前行的薪水例如,Philtanker的薪水2200,排在他之前的行中薪水大于等于2200-50的有1行,排在他之后的行中薪水小于等于2200+150的行没有,所以count计数值cnt3为2(包括自己当前行);cnt2值相当于小于等于当前行的SALARY值的所有行数
SELECT last_name, salary, COUNT(*) OVER () AS cnt1, COUNT(*) OVER (ORDER BY salary) AS cnt2, COUNT(*) OVER (ORDER BY salary RANGE BETWEEN 50 PRECEDING AND 150 FOLLOWING) AS cnt3 FROM employees;LAST_NAME SALARY CNT1 CNT2 CNT3------------------------- ---------- ---------- ---------- ----------Olson 2100 107 1 3Markle 2200 107 3 2Philtanker 2200 107 3 2Landry 2400 107 5 8Gee 2400 107 5 8Colmenares 2500 107 11 10Patel 2500 107 11 10..
CUME_DIST 功能描述:计算一行在组中的相对位置,CUME_DIST总是返回大于0、小于或等于1的数,该数表示该行在N行中的位置。例如,在一个3行的组中,返回的累计分布值为1/3、2/3、3/3
SAMPLE:下例中计算每个工种的员工按薪水排序依次累积出现的分布百分比
SELECT job_id, last_name, salary, CUME_DIST() OVER (PARTITION BY job_id ORDER BY salary) AS cume_dist FROM employees WHERE job_id LIKE @#PU%@#;JOB_ID LAST_NAME SALARY CUME_DIST---------- ------------------------- ---------- ----------PU_CLERK Colmenares 2500 .2PU_CLERK Himuro 2600 .4PU_CLERK Tobias 2800 .6PU_CLERK Baida 2900 .8PU_CLERK Khoo 3100 1PU_MAN Raphaely 11000 1
DENSE_RANK 功能描述:根据ORDER BY子句中表达式的值,从查询返回的每一行,计算它们与其它行的相对位置。组内的数据按ORDER BY子句排序,然后给每一行赋一个号,从而形成一个序列,该序列从1开始,往后累加。每次ORDER BY表达式的值发生变化时,该序列也随之增加。有同样值的行得到同样的数字序号(认为null时相等的)。密集的序列返回的值没有间隔的数
SAMPLE:下例中计算每个员工按部门分区再按薪水排序,依次出现的序列号(注意与RANK函数的区别)SELECT d.department_id , e.last_name, e.salary, DENSE_RANK() OVER (PARTITION BY e.department_id ORDER BY e.salary) as drank FROM employees e, departments dWHERE e.department_id = d.department_id AND d.department_id IN (@#60@#, @#90@#); DEPARTMENT_ID LAST_NAME SALARY DRANK------------- ------------------------- ---------- ---------- 60 Lorentz 4200 1 60 Austin 4800 2 60 Pataballa 4800 2 60 Ernst 6000 3 60 Hunold 9000 4 90 Kochhar 17000 1 90 De Haan 17000 1 90 King 24000 2
FIRST 功能描述:从DENSE_RANK返回的集合中取出排在最前面的一个值的行(可能多行,因为值可能相等),因此完整的语法需要在开始处加上一个集合函数以从中取出记录
SAMPLE:下面例子中DENSE_RANK按部门分区,再按佣金commission_pct排序,FIRST取出佣金最低的对应的所有行,然后前面的MAX函数从这个集合中取出薪水最低的值;LAST取出佣金最高的对应的所有行,然后前面的MIN函数从这个集合中取出薪水最高的值SELECT last_name, department_id, salary, MIN(salary) KEEP (DENSE_RANK FIRST ORDER BY commission_pct) OVER (PARTITION BY department_id) "Worst", MAX(salary) KEEP (DENSE_RANK LAST ORDER BY commission_pct) OVER (PARTITION BY department_id) "Best" FROM employees WHERE department_id in (20,80) ORDER BY department_id, salary;LAST_NAME DEPARTMENT_ID SALARY Worst Best------------------------- ------------- ---------- ---------- ----------Fay 20 6000 6000 13000Hartstein 20 13000 6000 13000Kumar 80 6100 6100 14000Banda 80 6200 6100 14000Johnson 80 6200 6100 14000Ande 80 6400 6100 14000Lee 80 6800 6100 14000Tuvault 80 7000 6100 14000Sewall 80 7000 6100 14000Marvins 80 7200 6100 14000Bates 80 7300 6100 14000...
FIRST_VALUE 功能描述:返回组中数据窗口的第一个值。
SAMPLE:下面例子计算按部门分区按薪水排序的数据窗口的第一个值对应的名字,如果薪水的第一个值有多个,则从多个对应的名字中取缺省排序的第一个名字SELECT department_id, last_name, salary, FIRST_VALUE(last_name) OVER (PARTITION BY department_id ORDER BY salary ASC ) AS lowest_sal FROM employees WHERE department_id in(20,30);DEPARTMENT_ID LAST_NAME SALARY LOWEST_SAL------------- ------------------------- ---------- -------------- 20 Fay 6000 Fay 20 Hartstein 13000 Fay 30 Colmenares 2500 Colmenares 30 Himuro 2600 Colmenares 30 Tobias 2800 Colmenares 30 Baida 2900 Colmenares 30 Khoo 3100 Colmenares 30 Raphaely 11000
LAG 功能描述:可以访问结果集中的其它行而不用进行自连接。它允许去处理游标,就好像游标是一个数组一样。在给定组中可参考当前行之前的行,这样就可以从组中与当前行一起选择以前的行。Offset是一个正整数,其默认值为1,若索引超出窗口的范围,就返回默认值(默认返回的是组中第一行),其相反的函数是LEAD(offset,default)
SAMPLE:下面的例子中列prev_sal返回按hire_date排序的前1行的salary值
SELECT last_name, hire_date, salary, LAG(salary, 1, 0) OVER (ORDER BY hire_date) AS prev_sal FROM employeesWHERE job_id = @#PU_CLERK@#;LAST_NAME HIRE_DATE SALARY PREV_SAL------------------------- ---------- ---------- ----------Khoo 18-5月 -95 3100 0Tobias 24-7月 -97 2800 3100Baida 24-12月-97 2900 2800Himuro 15-11月-98 2600 2900Colmenares 10-8月 -99 2500 2600
LAST 功能描述:从DENSE_RANK返回的集合中取出排在最后面的一个值的行(可能多行,因为值可能相等),因此完整的语法需要在开始处加上一个集合函数以从中取出记录
SAMPLE:下面例子中DENSE_RANK按部门分区,再按佣金commission_pct排序,FIRST取出佣金最低的对应的所有行,然后前面的MAX函数从这个集合中取出薪水最低的值;LAST取出佣金最高的对应的所有行,然后前面的MIN函数从这个集合中取出薪水最高的值SELECT last_name, department_id, salary, MIN(salary) KEEP (DENSE_RANK FIRST ORDER BY commission_pct) OVER (PARTITION BY department_id) "Worst", MAX(salary) KEEP (DENSE_RANK LAST ORDER BY commission_pct) OVER (PARTITION BY department_id) "Best" FROM employees WHERE department_id in (20,80) ORDER BY department_id, salary;LAST_NAME DEPARTMENT_ID SALARY Worst Best------------------------- ------------- ---------- ---------- ----------Fay 20 6000 6000 13000Hartstein 20 13000 6000 13000Kumar 80 6100 6100 14000Banda 80 6200 6100 14000Johnson 80 6200 6100 14000Ande 80 6400 6100 14000Lee 80 6800 6100 14000Tuvault 80 7000 6100 14000Sewall 80 7000 6100 14000Marvins 80 7200 6100 14000Bates 80 7300 6100 14000...
LAST_VALUE 功能描述:返回组中数据窗口的最后一个值。
SAMPLE:下面例子计算按部门分区按薪水排序的数据窗口的最后一个值对应的名字,如果薪水的最后一个值有多个,则从多个对应的名字中取缺省排序的最后一个名字
SELECT department_id, last_name, salary, LAST_VALUE(last_name) OVER(PARTITION BY department_id ORDER BY salary) AS highest_sal FROM employees WHERE department_id in(20,30);DEPARTMENT_ID LAST_NAME SALARY HIGHEST_SAL------------- ------------------------- ---------- ------------ 20 Fay 6000 Fay 20 Hartstein 13000 Hartstein 30 Colmenares 2500 Colmenares 30 Himuro 2600 Himuro 30 Tobias 2800 Tobias 30 Baida 2900 Baida 30 Khoo 3100 Khoo 30 Raphaely 11000 Raphaely
LEAD 功能描述:LEAD与LAG相反,LEAD可以访问组中当前行之后的行。Offset是一个正整数,其默认值为1,若索引超出窗口的范围,就返回默认值(默认返回的是组中第一行)SAMPLE:下面的例子中每行的"NextHired"返回按hire_date排序的下一行的hire_date值
SELECT last_name, hire_date, LEAD(hire_date, 1) OVER (ORDER BY hire_date) AS "NextHired" FROM employees WHERE department_id = 30;LAST_NAME HIRE_DATE NextHired------------------------- --------- ---------Raphaely 07-DEC-94 18-MAY-95Khoo 18-MAY-95 24-JUL-97Tobias 24-JUL-97 24-DEC-97Baida 24-DEC-97 15-NOV-98Himuro 15-NOV-98 10-AUG-99Colmenares 10-AUG-99
MAX 功能描述:在一个组中的数据窗口中查找表达式的最大值。
SAMPLE:下面例子中dept_max返回当前行所在部门的最大薪水值SELECT department_id, last_name, salary, MAX(salary) OVER (PARTITION BY department_id) AS dept_max FROM employees WHERE department_id in (10,20,30);DEPARTMENT_ID LAST_NAME SALARY DEPT_MAX------------- ------------------------- ---------- ---------- 10 Whalen 4400 4400 20 Hartstein 13000 13000 20 Fay 6000 13000 30 Raphaely 11000 11000 30 Khoo 3100 11000 30 Baida 2900 11000 30 Tobias 2800 11000 30 Himuro 2600 11000 30 Colmenares 2500 11000
MIN 功能描述:在一个组中的数据窗口中查找表达式的最小值。
SAMPLE:下面例子中dept_min返回当前行所在部门的最小薪水值
SELECT department_id, last_name, salary, MIN(salary) OVER (PARTITION BY department_id) AS dept_min FROM employees WHERE department_id in (10,20,30);DEPARTMENT_ID LAST_NAME SALARY DEPT_MIN------------- ------------------------- ---------- ---------- 10 Whalen 4400 4400 20 Hartstein 13000 6000 20 Fay 6000 6000 30 Raphaely 11000 2500 30 Khoo 3100 2500 30 Baida 2900 2500 30 Tobias 2800 2500 30 Himuro 2600 2500 30 Colmenares 2500 2500
NTILE 功能描述:将一个组分为"表达式"的散列表示,例如,如果表达式=4,则给组中的每一行分配一个数(从1到4),如果组中有20行,则给前5行分配1,给下5行分配2等等。如果组的基数不能由表达式值平均分开,则对这些行进行分配时,组中就没有任何percentile的行数比其它percentile的行数超过一行,最低的percentile是那些拥有额外行的percentile。例如,若表达式=4,行数=21,则percentile=1的有5行,percentile=2的有5行等等。
SAMPLE:下例中把6行数据分为4份SELECT last_name, salary, NTILE(4) OVER (ORDER BY salary DESC) AS quartile FROM employeesWHERE department_id = 100;LAST_NAME SALARY QUARTILE------------------------- ---------- ----------Greenberg 12000 1Faviet 9000 1Chen 8200 2Urman 7800 2Sciarra 7700 3Popp 6900 4
PERCENT_RANK 功能描述:和CUME_DIST(累积分配)函数类似,对于一个组中给定的行来说,在计算那行的序号时,先减1,然后除以n-1(n为组中所有的行数)。该函数总是返回0~1(包括1)之间的数。
SAMPLE:下例中如果Khoo的salary为2900,则pr值为0.6,因为RANK函数对于等值的返回序列值是一样的
SELECT department_id, last_name, salary, PERCENT_RANK() OVER (PARTITION BY department_id ORDER BY salary) AS pr FROM employeesWHERE department_id < 50 ORDER BY department_id,salary;DEPARTMENT_ID LAST_NAME SALARY PR------------- ------------------------- ---------- ---------- 10 Whalen 4400 0 20 Fay 6000 0 20 Hartstein 13000 1 30 Colmenares 2500 0 30 Himuro 2600 0.2 30 Tobias 2800 0.4 30 Baida 2900 0.6 30 Khoo 3100 0.8 30 Raphaely 11000 1 40 Mavris 6500 0
PERCENTILE_CONT 功能描述:返回一个与输入的分布百分比值相对应的数据值,分布百分比的计算方法见函数PERCENT_RANK,如果没有正好对应的数据值,就通过下面算法来得到值: RN = 1+ (P*(N-1)) 其中P是输入的分布百分比值,N是组内的行数 CRN = CEIL(RN) FRN = FLOOR(RN)if (CRN = FRN = RN) then (value of expression from row at RN) else (CRN - RN) * (value of expression for row at FRN) + (RN - FRN) * (value of expression for row at CRN) 注意:本函数与PERCENTILE_DISC的区别在找不到对应的分布值时返回的替代值的计算方法不同SAMPLE:在下例中,对于部门60的Percentile_Cont值计算如下: P=0.7 N=5 RN =1+ (P*(N-1)=1+(0.7*(5-1))=3.8 CRN = CEIL(3.8)=4 FRN = FLOOR(3.8)=3 (4 - 3.8)* 4800 + (3.8 - 3) * 6000 = 5760SELECT last_name, salary, department_id, PERCENTILE_CONT(0.7) WITHIN GROUP (ORDER BY salary) OVER (PARTITION BY department_id) "Percentile_Cont", PERCENT_RANK() OVER (PARTITION BY department_id ORDER BY salary) "Percent_Rank" FROM employees WHERE department_id IN (30, 60);LAST_NAME SALARY DEPARTMENT_ID Percentile_Cont Percent_Rank------------------------- ---------- ------------- --------------- ------------Colmenares 2500 30 3000 0Himuro 2600 30 3000 0.2Tobias 2800 30 3000 0.4Baida 2900 30 3000 0.6Khoo 3100 30 3000 0.8Raphaely 11000 30 3000 1Lorentz 4200 60 5760 0Austin 4800 60 5760 0.25Pataballa 4800 60 5760 0.25Ernst 6000 60 5760 0.75Hunold 9000 60 5760 1
PERCENTILE_DISC 功能描述:返回一个与输入的分布百分比值相对应的数据值,分布百分比的计算方法见函数CUME_DIST,如果没有正好对应的数据值,就取大于该分布值的下一个值。注意:本函数与PERCENTILE_CONT的区别在找不到对应的分布值时返回的替代值的计算方法不同
SAMPLE:下例中0.7的分布值在部门30中没有对应的Cume_Dist值,所以就取下一个分布值0.83333333所对应的SALARY来替代SELECT last_name, salary, department_id, PERCENTILE_DISC(0.7) WITHIN GROUP (ORDER BY salary ) OVER (PARTITION BY department_id) "Percentile_Disc", CUME_DIST() OVER (PARTITION BY department_id ORDER BY salary) "Cume_Dist" FROM employees WHERE department_id in (30, 60);LAST_NAME SALARY DEPARTMENT_ID Percentile_Disc Cume_Dist------------------------- ---------- ------------- --------------- ----------Colmenares 2500 30 3100 .166666667Himuro 2600 30 3100 .333333333Tobias 2800 30 3100 .5Baida 2900 30 3100 .666666667Khoo 3100 30 3100 .833333333Raphaely 11000 30 3100 1Lorentz 4200 60 6000 .2Austin 4800 60 6000 .6Pataballa 4800 60 6000 .6Ernst 6000 60 6000 .8Hunold 9000 60 6000 1
RANK 功能描述:根据ORDER BY子句中表达式的值,从查询返回的每一行,计算它们与其它行的相对位置。组内的数据按
ORDER BY子句排序,然后给每一行赋一个号,从而形成一个序列,该序列从1开始,往后累加。每次ORDER BY表达式的值发生变化时,该序列也随之增加。有同样值的行得到同样的数字序号(认为null时相等的)。然而,如果两行的确得到同样的排序,则序数将随后跳跃。若两行序数为1,则没有序数2,序列将给组中的下一行分配值3,DENSE_RANK则没有任何跳跃。
SAMPLE:下例中计算每个员工按部门分区再按薪水排序,依次出现的序列号(注意与DENSE_RANK函数的区别)SELECT d.department_id , e.last_name, e.salary, RANK() OVER (PARTITION BY e.department_id ORDER BY e.salary) as drank FROM employees e, departments dWHERE e.department_id = d.department_id AND d.department_id IN (@#60@#, @#90@#);DEPARTMENT_ID LAST_NAME SALARY DRANK------------- ------------------------- ---------- ---------- 60 Lorentz 4200 1 60 Austin 4800 2 60 Pataballa 4800 2 60 Ernst 6000 4 60 Hunold 9000 5 90 Kochhar 17000 1 90 De Haan 17000 1 90 King 24000 3
RATIO_TO_REPORT 功能描述:该函数计算expression/(sum(expression))的值,它给出相对于总数的百分比,即当前行对sum(expression)的贡献。
SAMPLE:下例计算每个员工的工资占该类员工总工资的百分比SELECT last_name, salary, RATIO_TO_REPORT(salary) OVER () AS rr FROM employeesWHERE job_id = @#PU_CLERK@#;LAST_NAME SALARY RR------------------------- ---------- ----------Khoo 3100 .223021583Baida 2900 .208633094Tobias 2800 .201438849Himuro 2600 .18705036Colmenares 2500 .179856115