程序人生

记录编程中的点点滴滴

Oracle的基于MODEL 子句的行级查询

操作环境

服务端Oracle 11g

客户端Oracle 10g

--准备脚本

DROP TABLE EMPLOYEE_SALARY_T;
CREATE TABLE EMPLOYEE_SALARY_T(
EMPLOYEE_ID         VARCHAR2(20),
EMPLOYEE_NAME       VARCHAR2(20),
DEPARTMENT          VARCHAR2(10),
COMPANY             VARCHAR2(10),
SALARY              NUMBER(6),
SALARY_YEAR         VARCHAR2(10)
);

INSERT INTO EMPLOYEE_SALARY_T VALUES('001','znp','dep001','VisSoft',30000,'2005');
INSERT INTO EMPLOYEE_SALARY_T VALUES('001','znp','dep001','VisSoft',40000,'2006');
INSERT INTO EMPLOYEE_SALARY_T VALUES('001','znp','dep001','VisSoft',50000,'2007');
INSERT INTO EMPLOYEE_SALARY_T VALUES('001','znp','dep001','VisSoft',60000,'2008');
                                                      
INSERT INTO EMPLOYEE_SALARY_T VALUES('002','zsj','dep001','AvsSoft',3000,'2005');
INSERT INTO EMPLOYEE_SALARY_T VALUES('002','zsj','dep001','AvsSoft',4000,'2006');
INSERT INTO EMPLOYEE_SALARY_T VALUES('002','zsj','dep001','AvsSoft',5000,'2007');
INSERT INTO EMPLOYEE_SALARY_T VALUES('002','zsj','dep001','AvsSoft',6000,'2008');
                                                       
INSERT INTO EMPLOYEE_SALARY_T VALUES('003','ts1','dep002','VisSoft',30000,'2005');
INSERT INTO EMPLOYEE_SALARY_T VALUES('003','ts1','dep002','VisSoft',40000,'2006');
INSERT INTO EMPLOYEE_SALARY_T VALUES('003','ts1','dep002','VisSoft',50000,'2007');
INSERT INTO EMPLOYEE_SALARY_T VALUES('003','ts1','dep002','VisSoft',60000,'2008');
                                                       
INSERT INTO EMPLOYEE_SALARY_T VALUES('004','ts2','dep002','AvsSoft',3000,'2005');
INSERT INTO EMPLOYEE_SALARY_T VALUES('004','ts2','dep002','AvsSoft',4000,'2006');
INSERT INTO EMPLOYEE_SALARY_T VALUES('004','ts2','dep002','AvsSoft',5000,'2007');
INSERT INTO EMPLOYEE_SALARY_T VALUES('004','ts2','dep002','AvsSoft',6000,'2008');

COMMIT;

--行级查询实现脚本
--查询含义为将09年dep001部门的salary预定为该部门05年、06年与08年的总和
--而dep002部门09年的salary预定为该部门06年、07年与08年的总和

SELECT COMPANY,DEPARTMENT,SALARYS FROM EMPLOYEE_SALARY_T
MODEL
     RETURN UPDATED ROWS        --是否显示基本查询行,如果有该行则不显示基本查询行,只显示查询计算结果行
     PARTITION BY (COMPANY)                   --分区,对行计算结果的分区,本例中以company列做为分区项
     DIMENSION BY (DEPARTMENT,SALARY_YEAR )   --决定两个计算的维度,当前表示第一维度为部门,第二维度为薪资年度
     MEASURES (SALARY SALARYS)                --我的理解是规则指向列,即对哪一列进行规则计算或规则改变
     RULES (
SALARYS['dep001', '2009'] = SALARYS['dep001', '2005'] + SALARYS['dep001', '2006']+ SALARYS['dep001', '2008'],
SALARYS['dep002', '2009'] = SALARYS['dep002', '2006'] + SALARYS['dep002', '2007']+ SALARYS['dep002', '2008']
);

想想如果用列级查询时实现的效果(^_^ 是不是比较地不麻烦)

PS:把COMPANY的值与DEPARTMENT的值调成同步,即DEPARTMENT为001时公司全部为AvsSoft,DEPARTMENT为002时公司全部为VisSoft。看看结果如何?

元旦快乐







posted on 2011-01-01 12:50 zhaonp 阅读(556) 评论(0)  编辑  收藏


只有注册用户登录后才能发表评论。


网站导航: