diff --git "a/37 \346\217\255\351\230\263\344\270\275/20231013 \347\252\227\345\217\243\345\207\275\346\225\260 \347\254\224\350\256\260.md" "b/37 \346\217\255\351\230\263\344\270\275/20231013 \347\252\227\345\217\243\345\207\275\346\225\260 \347\254\224\350\256\260.md" new file mode 100644 index 0000000000000000000000000000000000000000..e177a8f6a5d13936f04670ff2abc189932a5c0ab --- /dev/null +++ "b/37 \346\217\255\351\230\263\344\270\275/20231013 \347\252\227\345\217\243\345\207\275\346\225\260 \347\254\224\350\256\260.md" @@ -0,0 +1,313 @@ +# 函数复习 + +### 数学函数 + +```sql +-- 绝对值abs() +select abs(-4) -- 4 + +-- 向上取整 ceil(值) +select ceil(1.5) -- 2 + +-- 向下取整 floor(值) +select floor(1.5) -- 1 + +-- 随机数 rand() +select floor(rand()*100) + +-- 四舍五入,截取 round(值,保留点后n位) +select round(1.6666); +select round(1.6666,2); + +-- 截取 truncate(值,保留点后n位) + +``` + + + +### 字符串函数 + +```sql +-- 字符个数 +select char_length('abc') -- 3 +select char_length('软件工程') -- 4 + +-- 拼接字符串 +select concat('你','好','帅哥') +select concat_ws(',','你','好','帅哥') -- 第一个字符为分隔符 + +-- 去空 +select ltrim(' aaa'); +select rtrim('aaa '); +select trim(' aaa ') + +-- 截取 +select substr('hello',2,3); + +-- 获取子串在字符串的位置 +select position('a' in 'abc'); + +-- 替换 +select replace('aaabbbccc','a','1'); + +``` + + + +### 日期函数 + +```sql +-- 获取当前日期 +select curdate(); + +-- 获取当前时间 +select curtime(); + +-- 获取当前日期时间 +select now(); + +-- 从日期字符串获取日期 +select date('2000-02-02'); +select date('2000-02-02 12:12:12'); -- 只获取日期 + +-- 天数差 +select datediff('2001-02-02','2000-02-02'); -- 前减后 + +-- 指定差 +select timestampdiff(day,'2001-02-02','2000-02-02'); -- 后减前 + +-- 日期减法 +select subdate('2001-02-02',interval 2 day); + +-- 日期加法 +select adddate('2001-02-02',interval 2 day); + +-- 获取某日期中的值 +select year('2001-02-02'); +select day('2001-02-02'); +select dayofyear('2001-02-02'); +select dayofweek('2001-02-02'); + +-- 获取该月最后一天 +select last_day('2001-02-02'); + +-- 日期格式 +select date_format('2001-02-02','%Y') + +``` + +http://www.manongjc.com/detail/29-ensoneygersabbx.html + + + +# 控制流函数 + +```sql +-- if(表达式,值1,值2) true返回值1,false返回值2 +select if(1<2,1,2); + +-- ifnull(值1,值2) 如果值1不为null,返回值1,否则返回值2 +select ifnull(null,2); +select ifnull(1,2); + +-- isnull(表达式) 返回1或0 +select isnull(null); +select isnull(''); + +-- nullif(值1,值2) 比较两个值(字符串),如果当等返回null,否则返回值1 +select nullif(25,25); +``` + +```sql +-- case when +/* +语法1: +case + when 条件表达式1 then 值1 + when 条件表达式2 then 值2 + ... + else 值n +end + +语法2: +case 表达式 + when 条件值1 then 返回值1 + when 条件值2 then 返回值2 + ... + else 返回值n +end + +*/ +``` + + + +# 窗口函数 + +mysql 8.0新增窗口函数(开窗函数)。 + +非聚合窗口函数:是相对于聚合函数来说的,特性为非聚合。一次只处理一行数据。 + +窗口聚合函数:窗口聚合函数在单元行上计算某个字段的结果时,可将窗口范围内的数据输入到聚合函数中,并且不会改变行数。 + + + +### 语法 + +```sql +窗口函数名称(参数) over(partition by ... order by... 窗口大小) +``` + +partition by 分组,等价于group by + +order by 排序 + + + +### 序号函数 + +row_number()、rank()、dense_rank() + + + +### 开窗聚合函数 + +```sql +sum()|avg()|min()|max()|count()| over (partition by ... order by...) +``` + +案例: + +```sql +# 获取各部门薪金总和(合计) +select ename,hiredate,deptno,sal, +sum(sal) over(partition by deptno) 'sum' +from emp; + +# 获取各部门薪金总和(累加) +select ename,hiredate,deptno,sal, +sum(sal) over(partition by deptno order by sal) 'sum' +from emp; +``` + + + +#### 窗口大小 + +```sql +# 开窗范围 +# 获取各部门薪金总和(范围:初始行至当前行) +select ename,hiredate,deptno,sal, +sum(sal) over(partition by deptno rows between unbounded preceding and current row) 'sum' +from emp; + +-- rows 启用窗口大小 +-- between ... and ... 范围区间 +-- unbounded preceding 起始行 +-- current row 当前行 +``` + +不同案例: + +```sql +# 范围:前3行 + 当前行 +sum(sal) over(partition by deptno rows between 3 preceding and current row) + +# 范围:前3行 + 当前行 + 后1行 +sum(sal) over(partition by deptno rows between 3 preceding and 1 following) +-- following指当前行之后的行 + +# 范围:当前行至最后一行 +sum(sal) over(partition by deptno rows between current row and unbounded following) +-- unbounded following 最终行 +``` + + + +### 分布函数 + +##### cume_dist() + +分组内 <= 或 >= 当前值的行数占比(包含当前值本身) + +```sql +# 查询各部门员工小于等于当前薪资的比例 + +select ename,deptno,sal, +cume_dist() over(partition by deptno order by sal) '占比' +from emp; + +-- order by 控制计算的列 +-- asc 小于等于 +-- desc 大于等于 +``` + + + +### 前后函数 + +返回当前行的前某一行的值,或者后某一行的值 + +lag(列名,前第n行) + +lead(列名,后第n行) + +```sql +select ename,deptno,sal, +lag(sal,1) over(partition by deptno order by sal) '前1', +lag(sal,2) over(partition by deptno order by sal) '前2' +from emp; +``` + + + +### 头尾函数 + +返回第一个或最后一个列的值 + +first_value(列名) + +last_value(列名) + +```sql +-- 查询各个部门中,第一个和最后一个入职的员工姓名 +select ename,deptno,sal,hiredate, +first_value(ename) over(partition by deptno order by hiredate) 'first', +last_value(ename) over(partition by deptno order by hiredate) 'last' +from emp; +``` + + + +### 其他函数 + +nth_value(列名,n) —— 返回截止到当前行,该列的第n个值 + +```sql +-- 查找出各个部门,薪资排名第2的员工姓名 +select ename,deptno,sal, +nth_value(ename) over(partition by deptno order by sal) '第二名' +from emp; + +-- 查询全公司,薪资排名第2的员工姓名 +-- 1 +select ename,deptno,sal, +nth_value(ename,2) over(order by sal) '第二名' +from emp; +-- 2 +select ename,deptno,sal, +nth_value(ename,2) over() '第二名' +from emp order by sal; +``` + +ntile(n) —— 将分区中的有序数据分为n个等级,记录等级数 + +```sql +-- 将每个部门员工按照入职日期分成3组 +select ename,deptno,sal, +ntile(3) over(partition by deptno order by hiredate) '组别' +from emp; + +-- 找出每个部门中的老员工?? +``` + diff --git "a/37 \346\217\255\351\230\263\344\270\275/20231013 \347\252\227\345\217\243\345\207\275\346\225\260.md" "b/37 \346\217\255\351\230\263\344\270\275/20231013 \347\252\227\345\217\243\345\207\275\346\225\260.md" new file mode 100644 index 0000000000000000000000000000000000000000..32b781ee12cc0b05a0b0517defba3281c6cc8245 --- /dev/null +++ "b/37 \346\217\255\351\230\263\344\270\275/20231013 \347\252\227\345\217\243\345\207\275\346\225\260.md" @@ -0,0 +1,332 @@ +## 课后练习 + +```sql +CREATE DATABASE uu charset utf8; +use uu; + +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); +``` + +```sql +-- 员工按工龄,每年增加50元薪水。实发薪资 = 基本薪资 + 工龄 * 50 + + +### -- 窗口函数 + +select * 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 DISTINCT + dname 部门, + ename 姓名, + salary 工资, + rank() over ( PARTITION BY dname ORDER BY salary desc ) 平均薪资 +FROM + employee ; +#求公司所有员工的年龄排序(相同年龄并列,执行跳过排序) + +SELECT + ename 姓名, + birth 生日, + RANK() over ( ORDER BY birth DESC ) 排名 +FROM + employee; + + +#求每个部门的员工工龄排序(相同年龄并列,执行顺序排序) +SELECT + ename 姓名, + hiredate 工龄, + DENSE_RANK() over ( ORDER BY hiredate DESC ) 排名 +FROM + employee; + +#计算每个员工的工资与该部门平均工资的差额 +SELECT + ename 员工, + dname 部门, + salary 工资, + AVG( salary ) over ( PARTITION BY dname )- salary +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; +``` +