ORACLE - 开窗+分析函数

it2022-05-05  207

      分析函数是Oracle专门用于解决复杂报表统计需求的功能强大的函数,它可以在数据中进行分组然后计算基于组的某种统计值,并且每一组的每一行都可以返回一个统计值。

     开窗函数指定了函数所能影响的窗口范围,也就是说在这个窗口范围中都可以受到函数的影响,有些分析函数就是开窗函数。

 

开窗函数over 存在两种情况 一种只使用 partition by 做分组 后 全组范围内分析,第二种是 加 order by 是一个分组后连续分析的概念(对 连续结果集 做操作)

 

 

原数据列如下

 

1、sum/avg... + over(partition by )  分组全范围计算

with temp as ( select 1 id, 'A' name, 20 age, '研发部' dept, 1000 amt, 1 state from dual union all select 2 id, 'B' name, 22 age, '测试部' dept, 2000 amt, 0 state from dual union all select 3 id, 'C' name, 24 age, '架构部' dept, 3000 amt, 1 state from dual union all select 4 id, 'D' name, 23 age, '研发部' dept, 4000 amt, 1 state from dual union all select 5 id, 'E' name, 23 age, '测试部' dept, 5000 amt, 0 state from dual union all select 6 id, 'F' name, 22 age, '架构部' dept, 6000 amt, 1 state from dual union all select 7 id, 'G' name, 25 age, '研发部' dept, 7000 amt, 1 state from dual union all select 8 id, 'H' name, 25 age, '测试部' dept, 8000 amt, 0 state from dual ) select temp.*, sum(amt) over(partition by age) age_amt_sum, -- 每个年龄段的 工资总和 avg(amt) over(partition by age) age_amt_avg, -- 每个年龄段的 平均工资 count(*) over(partition by age) age_nums, -- 每个年龄段 员工数 count(distinct name) over(partition by age) age_disname_nums, -- 每个年龄段 员工数 去重 count(distinct case when state = 1 then name end) over() state1_nums, -- state = 1 的数量 count(distinct case when state = 0 then name end) over() state0_nums, -- state = 0 的数量 max(amt) over(partition by age) age_max_amt, -- 每个年龄段的最大工资 min(amt) over(partition by age) age_min_amt, -- 每个年龄段的最小工资 row_number() over(partition by age order by amt desc) rn, -- 每个年龄段工资排名 RATIO_TO_REPORT(amt) over(partition by age) rate, -- 每个年龄段内工资占比 sum(amt) over(order by age rows between unbounded preceding and current row) amt_sum, -- 从第一行到当前行 amt 累计求和 sum(amt) over(order by age range between unbounded preceding and current row) amt_sum2 -- 从第一行到当前行 age_amt_sum 累计求和(同样的年龄是一个范围) from temp;

结果集

其中排名函数有3个

row_number( ):返回一个唯一的值,当碰到相同数据时,排名按照记录集中记录的顺序依次递增。

rank( ):返回一个唯一的值,当碰到相同的数据时,此时所有相同数据的排名是一样的,同时会在最后一条相同记录和下一条不同记录的排名之间空出排名。

 dense_rank( ):返回一个唯一的值,当碰到相同数据时,此时所有相同数据的排名都是一样的,同时会在最后一条相同记录和下一条不同记录的排名之间紧邻递增。 over关键字后的括号中的选项为空,则开窗函数会对结果集中的所有行进行聚合运算;over关键字后的括号中的选项为不为空,则按照括号中的范围进行聚合运算。

 

 

2、sum/avg  ... + over(partition by order by)  分组且连续计算

with temp as ( select 1 id, 'A' name, 20 age, '研发部' dept, 1000 amt from dual union all select 2 id, 'B' name, 22 age, '测试部' dept, 2000 amt from dual union all select 3 id, 'C' name, 24 age, '架构部' dept, 3000 amt from dual union all select 4 id, 'D' name, 23 age, '研发部' dept, 4000 amt from dual union all select 5 id, 'E' name, 23 age, '测试部' dept, 5000 amt from dual union all select 6 id, 'F' name, 22 age, '架构部' dept, 6000 amt from dual union all select 7 id, 'G' name, 25 age, '研发部' dept, 7000 amt from dual union all select 8 id, 'H' name, 25 age, '测试部' dept, 8000 amt from dual ) select temp.*, sum(amt) over(partition by dept order by age) dept_amt_sum, -- 每个部门 按照年龄排序 连续累计和 avg(amt) over(partition by dept order by age) dept_amt_avg, -- 每个部门 按照年龄段的 连续求平均工资 count(*) over(partition by dept order by age) dept_age_nums, -- 每个部门根据年龄 报数 (连续计数) max(amt) over(partition by dept order by age) age_max_amt -- 每个部门根据年龄排序 连续取最大值 from temp;

结果集

 

 

 

3、小例子: 利用 log + over 计算同比环比值

with temp as ( select 1 id, 2017 t_year, 6 t_month, '6000' t_amt, 'A' dept from dual union all select 2 id, 2017 t_year, 7 t_month, '7000' t_amt, 'A' dept from dual union all select 3 id, 2017 t_year, 8 t_month, '8000' t_amt, 'A' dept from dual union all select 4 id, 2017 t_year, 9 t_month, '9000' t_amt, 'A' dept from dual union all select 5 id, 2017 t_year, 10 t_month, '10000' t_amt, 'A' dept from dual union all select 6 id, 2017 t_year, 11 t_month, '11000' t_amt, 'A' dept from dual union all select 7 id, 2017 t_year, 12 t_month, '12000' t_amt, 'A' dept from dual union all select 8 id, 2018 t_year, 1 t_month, '1000' t_amt, 'A' dept from dual union all select 9 id, 2018 t_year, 2 t_month, '2000' t_amt, 'A' dept from dual union all select 10 id, 2018 t_year, 3 t_month, '3000' t_amt, 'A' dept from dual union all select 11 id, 2018 t_year, 4 t_month, '4000' t_amt, 'A' dept from dual union all select 12 id, 2018 t_year, 5 t_month, '5000' t_amt, 'A' dept from dual union all select 13 id, 2018 t_year, 6 t_month, '6000' t_amt, 'A' dept from dual union all select 14 id, 2018 t_year, 7 t_month, '7000' t_amt, 'A' dept from dual union all select 15 id, 2018 t_year, 8 t_month, '8000' t_amt, 'A' dept from dual union all select 16 id, 2018 t_year, 9 t_month, '9000' t_amt, 'A' dept from dual union all select 17 id, 2018 t_year, 10 t_month, '10000' t_amt, 'A' dept from dual union all select 18 id, 2018 t_year, 11 t_month, '11000' t_amt, 'A' dept from dual union all select 19 id, 2018 t_year, 12 t_month, '12000' t_amt, 'A' dept from dual union all select 20 id, 2019 t_year, 1 t_month, '1000' t_amt, 'A' dept from dual union all select 21 id, 2019 t_year, 2 t_month, '2000' t_amt, 'A' dept from dual union all select 22 id, 2019 t_year, 3 t_month, '3000' t_amt, 'A' dept from dual union all select 23 id, 2019 t_year, 4 t_month, '4000' t_amt, 'A' dept from dual union all select 24 id, 2019 t_year, 5 t_month, '5000' t_amt, 'A' dept from dual union all select 25 id, 2019 t_year, 6 t_month, '6000' t_amt, 'A' dept from dual union all select 26 id, 2019 t_year, 7 t_month, '7000' t_amt, 'A' dept from dual union all select 28 id, 2017 t_year, 6 t_month, '6000' t_amt, 'B' dept from dual union all select 29 id, 2017 t_year, 7 t_month, '7000' t_amt, 'B' dept from dual union all select 30 id, 2017 t_year, 8 t_month, '8000' t_amt, 'B' dept from dual union all select 31 id, 2017 t_year, 9 t_month, '9000' t_amt, 'B' dept from dual union all select 32 id, 2017 t_year, 10 t_month, '10000' t_amt, 'B' dept from dual union all select 33 id, 2017 t_year, 11 t_month, '11000' t_amt, 'B' dept from dual union all select 34 id, 2017 t_year, 12 t_month, '12000' t_amt, 'B' dept from dual union all select 35 id, 2018 t_year, 1 t_month, '1000' t_amt, 'B' dept from dual union all select 36 id, 2018 t_year, 2 t_month, '2000' t_amt, 'B' dept from dual union all select 37 id, 2018 t_year, 3 t_month, '3000' t_amt, 'B' dept from dual union all select 38 id, 2018 t_year, 4 t_month, '4000' t_amt, 'B' dept from dual union all select 39 id, 2018 t_year, 5 t_month, '5000' t_amt, 'B' dept from dual union all select 40 id, 2018 t_year, 6 t_month, '6000' t_amt, 'B' dept from dual union all select 41 id, 2018 t_year, 7 t_month, '7000' t_amt, 'B' dept from dual union all select 42 id, 2018 t_year, 8 t_month, '8000' t_amt, 'B' dept from dual union all select 43 id, 2018 t_year, 9 t_month, '9000' t_amt, 'B' dept from dual union all select 44 id, 2018 t_year, 10 t_month, '10000' t_amt, 'B' dept from dual union all select 45 id, 2018 t_year, 11 t_month, '11000' t_amt, 'B' dept from dual union all select 46 id, 2018 t_year, 12 t_month, '12000' t_amt, 'B' dept from dual union all select 47 id, 2019 t_year, 1 t_month, '1000' t_amt, 'B' dept from dual union all select 48 id, 2019 t_year, 2 t_month, '2000' t_amt, 'B' dept from dual union all select 49 id, 2019 t_year, 3 t_month, '3000' t_amt, 'B' dept from dual union all select 50 id, 2019 t_year, 4 t_month, '4000' t_amt, 'B' dept from dual union all select 51 id, 2019 t_year, 5 t_month, '5000' t_amt, 'B' dept from dual union all select 52 id, 2019 t_year, 6 t_month, '6000' t_amt, 'B' dept from dual union all select 53 id, 2019 t_year, 7 t_month, '7000' t_amt, 'B' dept from dual ) select tab.dept, tab.t_year, tab.t_month, tab.t_amt, case -- 判断是否为上一个月 when (tab.pre_month+1 = tab.t_month) or (tab.t_month = 1 and tab.pre_month=12 and tab.pre_year+1 = tab.t_year) then decode(tab.pre_amt,null,null,0,null,round(tab.t_amt/tab.pre_amt,2)) else null end as 环比, case -- 判断是否上一年 同一个月 when (tab.t_month = tab.last_month and tab.last_year+1 = tab.t_year) then decode(tab.last_amt,null,null,0,null,round(tab.t_amt/tab.last_amt,2)) else null end as 同比 from ( select t.dept, t.t_year, t.t_month, t.t_amt, lag(t.t_year,1,-1) over(partition by t.dept order by t.t_year,t.t_month) pre_year, -- 上个月所在年 lag(t.t_month,1,-1) over(partition by t.dept order by t.t_year,t.t_month) pre_month, -- 上个月 lag(t.t_amt,1,null) over(partition by t.dept order by t.t_year,t.t_month) pre_amt, -- 上个月值 lag(t.t_year,12,-1) over(partition by t.dept order by t.t_year,t.t_month) last_year, -- 去年 lag(t.t_month,12,-1) over(partition by t.dept order by t.t_year,t.t_month) last_month, -- 去年同月 lag(t.t_amt,12,null) over(partition by t.dept order by t.t_year,t.t_month) last_amt -- 去年同月值 from temp t ) tab

 

 

 


最新回复(0)