From 0a7dea065df62beda47bb8f033f5587e7a4d5371 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?=E5=91=A8=E5=8E=9A=E8=BE=B0?= Date: Mon, 16 Oct 2023 20:19:19 +0800 Subject: [PATCH] twenty-first --- ...27\345\217\243\345\207\275\346\225\260.md" | 318 ++++++++++++++++++ 1 file changed, 318 insertions(+) create mode 100644 "53 \345\221\250\345\216\232\350\276\260/20231016 \347\254\254\344\272\214\345\215\201\344\270\200\346\254\241\344\275\234\344\270\232 \347\252\227\345\217\243\345\207\275\346\225\260/\347\252\227\345\217\243\345\207\275\346\225\260.md" diff --git "a/53 \345\221\250\345\216\232\350\276\260/20231016 \347\254\254\344\272\214\345\215\201\344\270\200\346\254\241\344\275\234\344\270\232 \347\252\227\345\217\243\345\207\275\346\225\260/\347\252\227\345\217\243\345\207\275\346\225\260.md" "b/53 \345\221\250\345\216\232\350\276\260/20231016 \347\254\254\344\272\214\345\215\201\344\270\200\346\254\241\344\275\234\344\270\232 \347\252\227\345\217\243\345\207\275\346\225\260/\347\252\227\345\217\243\345\207\275\346\225\260.md" new file mode 100644 index 0000000..f594c56 --- /dev/null +++ "b/53 \345\221\250\345\216\232\350\276\260/20231016 \347\254\254\344\272\214\345\215\201\344\270\200\346\254\241\344\275\234\344\270\232 \347\252\227\345\217\243\345\207\275\346\225\260/\347\252\227\345\217\243\345\207\275\346\225\260.md" @@ -0,0 +1,318 @@ +2023年10月16日 + +# 窗口函数 + +## 作业题目 + +```mysql +create table if not exists `employee` +( + `eid` int not null auto_increment comment '员工id' primary key, + `ename` varchar(20) not null comment '员工名称', + `dname` varchar(50) not null comment '部门名称', + `hiredate` datetime not null comment '入职日期', + `birth` date not null comment '生日', + `salary` double null comment '基本薪资', + `start_sal` double null comment '入职薪资' +); + +insert into `employee` (`ename`, `dname`, `hiredate`,`birth`, `salary`,`start_sal`) values ('傅嘉熙', '开发部', '2002-08-20 12:00:04','1980-12-10', 9000,6500); +insert into `employee` (`ename`, `dname`, `hiredate`, `birth`,`salary`,`start_sal`) values ('武晟睿', '开发部', '2002-06-12 13:54:12', '1984-2-5',9500,6000); +insert into `employee` (`ename`, `dname`, `hiredate`, `birth`,`salary`,`start_sal`) values ('孙弘文', '开发部', '2003-10-16 08:27:06','1979-8-7', 9400,8000); +insert into `employee` (`ename`, `dname`, `hiredate`,`birth`, `salary`,`start_sal`) values ('潘乐驹', '开发部', '2004-04-22 03:56:11','1980-5-12', 9500,6800); +insert into `employee` (`ename`, `dname`, `hiredate`,`birth`, `salary`,`start_sal`) values ('潘昊焱', '人事部', '2007-02-24 03:40:02','1987-2-12', 5000,4500); +insert into `employee` (`ename`, `dname`, `hiredate`,`birth`, `salary`,`start_sal`) values ('沈涛', '人事部', '2012-12-14 09:16:37','1993-4-30', 6000,5500); +insert into `employee` (`ename`, `dname`, `hiredate`, `birth`,`salary`,`start_sal`) values ('江峻熙', '人事部', '2018-05-12 01:17:48','1990-6-8', 5000,3000); +insert into `employee` (`ename`, `dname`, `hiredate`,`birth`, `salary`,`start_sal`) values ('陆远航', '人事部', '2018-04-14 03:35:57','1989-11-13', 5500,5000); +insert into `employee` (`ename`, `dname`, `hiredate`, `birth`,`salary`,`start_sal`) values ('姜煜祺', '销售部', '2020-03-23 03:21:05','1995-1-1', 6000,5500); +insert into `employee` (`ename`, `dname`, `hiredate`, `birth`,`salary`,`start_sal`) values ('邹明', '销售部', '2015-11-23 23:10:06','1996-2-19', 6800,6000); +insert into `employee` (`ename`, `dname`, `hiredate`, `birth`,`salary`,`start_sal`) values ('董擎苍', '销售部', '2012-02-12 07:54:32','1985-10-7', 6500,4800); +insert into `employee` (`ename`, `dname`, `hiredate`,`birth`, `salary`,`start_sal`) values ('钟俊驰', '销售部', '2010-04-10 12:17:06','1981-3-25', 6000,3500); +``` + + + +## 作业答案 + +```mysql +-- 员工按工龄,每年增加50元薪水。实发薪资 = 基本薪资 + 工龄 * 50 +SELECT + * +FROM + employee;### -- 窗口函数 +SELECT + dname, + ename, + salary, + rank() over ( ORDER BY salary DESC ) +FROM + employee;#求每个部门的员工总数 +SELECT DISTINCT + dname 部门, + COUNT( ename ) over ( PARTITION BY dname ) 员工总数 +FROM + employee;#求每个部门的平均工资 +SELECT DISTINCT + dname 部门, + AVG( salary ) over ( PARTITION BY dname ) 平均工资 +FROM + employee;#求每个部门的工资排名(从高到低,相同工资并列,并执行跳过排序) +SELECT + RANK() over ( PARTITION BY dname ORDER BY salary DESC ) 工资排名, + ename, + dname, + salary +FROM + employee;#求公司所有员工的年龄排序(相同年龄并列,执行跳过排序) +SELECT + RANK() over ( ORDER BY DATEDIFF( NOW(), birth ) DIV 365 ) 年龄排序, + ename, + DATEDIFF( NOW(), birth ) DIV 365 `年龄` +FROM + employee;#求每个部门的员工工龄排序(相同年龄并列,执行顺序排序) +SELECT + dense_rank() over ( + PARTITION BY dname + ORDER BY + YEAR ( + NOW())- YEAR ( birth )) 年龄排序, + ename, + dname, + YEAR ( + NOW())- YEAR ( birth ) `年龄` +FROM + employee;#计算每个员工的工资与该部门平均工资的差额 +SELECT + ename, + dname, + salary 工资, + AVG( salary ) over ( PARTITION BY dname ) `部门平均工资`, + ABS(( + salary - AVG( salary ) over ( PARTITION BY dname ))) 与部门平均工资差额 +FROM + employee;#按员工工资进行排序,比较相邻两个员工的工资,输出比较高的工资 +SELECT + ename, + salary `工资`, + MAX( salary ) over ( rows BETWEEN 1 preceding AND 1 following ) 较高的工资 +FROM + employee;#按员工工资进行排序,查询当前员工与前一位和后一位的工资平均值 +SELECT + ename, + salary 工资, + TRUNCATE ( + avg( salary ) over ( rows BETWEEN 1 preceding AND 1 following ), + 0 + ) 前一位和后一位的工资平均值 +FROM + employee;#按员工工资进行排序,查询当前员工至最后一位员工的工资总和 +SELECT + ename, + salary, + sum( salary ) over ( rows BETWEEN current ROW AND unbounded following ) 至最后一位员工的工资总和 +FROM + employee;#计算每个部门内最高薪资与平均薪资的差额 +SELECT DISTINCT + dname, + max( salary ) over ( PARTITION BY dname )- avg( salary ) over ( PARTITION BY dname ) 最高薪资与平均薪资的差额 +FROM + employee;#找出各部门年薪第二高的员工 +SELECT + * +FROM + ( + SELECT + ename, + dname, + salary, + dense_RANK() over ( PARTITION BY dname ORDER BY salary ) `ranks` + FROM + employee + ) r +WHERE + ranks = 2;#查询各部门中小于等于当前员工实际薪资的比例 +SELECT + dname, + ename, + salary, + cume_dist() over ( PARTITION BY dname ORDER BY salary ASC ) +FROM + employee;#查询每个员工工资在全部员工中的排名比例 +SELECT + RANK() OVER w, + ename, + salary, + TRUNCATE ( PERCENT_RANK() over w, 2 ) +FROM + employee window w AS ( ORDER BY salary DESC );#查询每个部门工资排名在前25%的员工记录数 +SELECT + * +FROM + ( + SELECT + dname, + ename, + salary, + TRUNCATE ( + PERCENT_RANK() over ( PARTITION BY dname ORDER BY salary ), + 2 + ) 工资比例 + FROM + employee + ) p +WHERE + 工资比例 >= 0.25;#每个部门按年龄进行排序,求当前员工与前一位员工的年龄差 +SELECT + ename, + dname, + birth, + TRUNCATE ( + DATEDIFF( + NOW(), + LAG( birth, 1 ) over ( PARTITION BY dname ))/ 365, + 0 + ) 当前员工与前一位员工的年龄差 +FROM + employee;#按入职日期进行排序,查询公司每个员工与后面一个员工的入职天数差异 +SELECT + ename, + hiredate, + DATEDIFF( + hiredate, + lead( hiredate, 1 ) over ()) +FROM + employee;#将每个部门的员工按工资平均分为2个组,组1为低工资,组2为高工资 +SELECT + ntile( 2 ) over ( PARTITION BY dname ORDER BY salary ) 组, + ename, + dname, + salary +FROM + employee;#将所有员工按照工龄分为4个组,并统计每个组的人数 +SELECT + a.*, + COUNT(组别) over ( PARTITION BY 组别 ) 每个组的人数 +FROM + ( + SELECT + ename, + hiredate, + TRUNCATE (( DATEDIFF( NOW(), birth )/ 365 ), 0 ) 工龄, + NTILE( 4 ) over ( + + ORDER BY + ( DATEDIFF( NOW(), birth )/ 365 )) `组别` + FROM + employee + ) a;#将员工按照工资分为3个组,并统计组别,每组平均工资,工资范围(first_value、last_value) +SELECT + a.*, + AVG( salary ) over w 每组平均工资, + first_value( salary ) over w, + last_value( salary ) over w +FROM + ( + SELECT + ename, + salary, + NTILE( 3 ) over ( ORDER BY salary ) 组别 + FROM + employee + ) a window w AS ( PARTITION BY a.组别 );### -- 非窗口函数 +#按照工龄区分等级,小于5年为新员工,5-15年为老员工,大于15年为骨灰级员工,输出姓名,部门,工龄,级别 +SELECT + t.*, +CASE + + WHEN t.`工龄` < 5 THEN + '新员工' + WHEN t.`工龄` BETWEEN 5 + AND 15 THEN + '老员工' ELSE '骨灰级员工' + END 级别 +FROM + ( + SELECT + ename, + dname, + hiredate, + TRUNCATE (( DATEDIFF( NOW(), birth )/ 365 ), 0 ) 工龄 + FROM + employee + ) t;#返回员工的实际年龄,如果小于当前日期则减1岁 +SELECT + ename, + hiredate,( + YEAR ( + NOW())- YEAR ( birth ))- +CASE + + WHEN date_format( NOW(), '%m%d' )> DATE_FORMAT( birth, '%m%d' ) THEN + 0 ELSE 1 + END 年龄 +FROM + employee;#求每个员工还有多少天过生日,并返回下次生日是星期几 +SELECT + ename, + CONCAT_WS( '-', MONTH ( birth ), DAY ( birth ) ) 生日, + DATEDIFF( + CURRENT_DATE (), + CONCAT_WS( + '-', + YEAR ( CURRENT_DATE ), + MONTH ( birth ), + DAY ( birth ) + ) + ) 距离下次生日的天数, +CASE + DATE_FORMAT( + CONCAT_WS( + '-', + CASE + + WHEN DATEDIFF( + CURRENT_DATE (), + CONCAT_WS( + '-', + YEAR ( CURRENT_DATE ), + MONTH ( birth ), + DAY ( birth ) + ) + ) > 0 THEN + YEAR ( CURRENT_DATE )+ 1 ELSE YEAR ( CURRENT_DATE ) + END, + MONTH ( birth ), + DAY ( birth ) + ), + '%w' + ) + WHEN 0 THEN + '周日' + WHEN 1 THEN + '周一' + WHEN 2 THEN + '周二' + WHEN 3 THEN + '周三' + WHEN 4 THEN + '周四' + WHEN 5 THEN + '周五' + WHEN 6 THEN + '周六' + END 下次生日的星期 +FROM + employee;#求每个员工当前实发工资与入职时工资的增长率,输出员工姓名,部门,入职工资,实际工资,增长率 +SELECT + ename, + dname, + start_sal, + salary, + CONCAT( + format(( salary - start_sal )/ start_sal * 100, 2 ), + '%' + ) +FROM + employee; +``` + -- Gitee