这是一道Leetcode
数据库部分的Hard
题,本文决定采用最简单的方式来一步一步分解
题目:部门工资前三高的所有员工
Employee
表包含所有员工信息,每个员工有其对应的工号 Id
,姓名 Name
,工资 Salary
和部门编号 DepartmentId
。
+----+-------+--------+--------------+
| Id | Name | Salary | DepartmentId |
+----+-------+--------+--------------+
| 1 | Joe | 85000 | 1 |
| 2 | Henry | 80000 | 2 |
| 3 | Sam | 60000 | 2 |
| 4 | Max | 90000 | 1 |
| 5 | Janet | 69000 | 1 |
| 6 | Randy | 85000 | 1 |
| 7 | Will | 70000 | 1 |
+----+-------+--------+--------------+
Department
表包含公司所有部门的信息。
+----+----------+
| Id | Name |
+----+----------+
| 1 | IT |
| 2 | Sales |
+----+----------+
编写一个 SQL
查询,找出每个部门获得前三高工资的所有员工。例如,根据上述给定的表,查询结果应返回:
+------------+----------+--------+
| Department | Employee | Salary |
+------------+----------+--------+
| IT | Max | 90000 |
| IT | Randy | 85000 |
| IT | Joe | 85000 |
| IT | Will | 70000 |
| Sales | Henry | 80000 |
| Sales | Sam | 60000 |
+------------+----------+--------+
解释:
IT
部门中,Max
获得了最高的工资,Randy
和Joe
都拿到了第二高的工资,Will
的工资排第三。销售部门(Sales
)只有两名员工,Henry
的工资最高,Sam 的工资排第二。
来源:力扣(LeetCode) 链接:https://leetcode-cn.com/problems/department-top-three-salaries 著作权归领扣网络所有。商业转载请联系官方授权,非商业转载请注明出处。
Create table If Not Exists Employee (Id int, Name varchar(255), Salary int, DepartmentId int);
Create table If Not Exists Department (Id int, Name varchar(255));
Truncate table Employee;
insert into Employee (Id, Name, Salary, DepartmentId) values ('1', 'Joe', '85000', '1');
insert into Employee (Id, Name, Salary, DepartmentId) values ('2', 'Henry', '80000', '2');
insert into Employee (Id, Name, Salary, DepartmentId) values ('3', 'Sam', '60000', '2');
insert into Employee (Id, Name, Salary, DepartmentId) values ('4', 'Max', '90000', '1');
insert into Employee (Id, Name, Salary, DepartmentId) values ('5', 'Janet', '69000', '1');
insert into Employee (Id, Name, Salary, DepartmentId) values ('6', 'Randy', '85000', '1');
insert into Employee (Id, Name, Salary, DepartmentId) values ('7', 'Will', '70000', '1');
Truncate table Department;
insert into Department (Id, Name) values ('1', 'IT');
insert into Department (Id, Name) values ('2', 'Sales');
题解
进行三步分解
- 先对每个部门的工资进行排行
- 取出每个部门工资前三高的人的信息
- 使用
Department.Name
代替Employee.DepartmentID
先对每个部门的工资进行排行
我们先理解什么是排名,排名就是看看比你多的工资有多少个人,比如说总共有工资档次:200 100 50 20
要取50的排名就是看看大于等于50
一共有几个档次,这里我们看到有3个档次200 150 50
,所以你的排名就是第三名.所以我们可以按照这个意思来写SQL
select DepartmentId,
Name,
`Salary`,
(select count(distinct `Salary`) from `Employee` b
where b.Salary >= a.Salary
and a.`DepartmentId` = b.DepartmentId
) as `Rank`
from `Employee` a
查出的结果集为
+--------------+-------+--------+------+
| DepartmentId | Name | Salary | Rank |
+--------------+-------+--------+------+
| 1 | Joe | 85000 | 2 |
| 2 | Henry | 80000 | 1 |
| 2 | Sam | 60000 | 2 |
| 1 | Max | 90000 | 1 |
| 1 | Janet | 69000 | 4 |
| 1 | Randy | 85000 | 2 |
| 1 | Will | 70000 | 3 |
+--------------+-------+--------+------+
-- 按照 DepartmentId,Rank 排序来看就是
+--------------+-------+--------+------+
| DepartmentId | Name | Salary | Rank |
+--------------+-------+--------+------+
| 1 | Max | 90000 | 1 |
| 1 | Randy | 85000 | 2 |
| 1 | Joe | 85000 | 2 |
| 1 | Will | 70000 | 3 |
| 1 | Janet | 69000 | 4 |
| 2 | Henry | 80000 | 1 |
| 2 | Sam | 60000 | 2 |
+--------------+-------+--------+------+
取出每个部门工资前三高的人的信息
这里很明显就是写一个where
条件
select *
from (
select DepartmentId,
Name,
`Salary`,
(select count(distinct `Salary`) from `Employee` b
where b.Salary >= a.Salary
and a.`DepartmentId` = b.DepartmentId
) as `Rank`
from `Employee` a
)a
where
`rank` <= 3
查出来的结果集为
+--------------+-------+--------+------+
| DepartmentId | Name | Salary | Rank |
+--------------+-------+--------+------+
| 1 | Joe | 85000 | 2 |
| 2 | Henry | 80000 | 1 |
| 2 | Sam | 60000 | 2 |
| 1 | Max | 90000 | 1 |
| 1 | Randy | 85000 | 2 |
| 1 | Will | 70000 | 3 |
+--------------+-------+--------+------+
-- 按照 DepartmentId,Rank 排序来看就是
+--------------+-------+--------+------+
| DepartmentId | Name | Salary | Rank |
+--------------+-------+--------+------+
| 1 | Max | 90000 | 1 |
| 1 | Randy | 85000 | 2 |
| 1 | Joe | 85000 | 2 |
| 1 | Will | 70000 | 3 |
| 2 | Henry | 80000 | 1 |
| 2 | Sam | 60000 | 2 |
+--------------+-------+--------+------+
使用Department.Name
代替Employee.DepartmentID
使用Department.Name
代替Employee.DepartmentID
这里可以看到只要连表查一下就可以了,这个代码应该不难
select b.`Name` as `Department`, a.Name as Employee,Salary
from (
select
DepartmentId,
Name,
`Salary`,
(
select
count(distinct `Salary`)
from
`Employee` b
where
b.Salary>=a.Salary and a.`DepartmentId` = b.DepartmentId
) as `Rank`
from `Employee` a
)a left join `Department` b on a.DepartmentId = b.id
where
`rank` <= 3
and
b.`name` is not null;
-- 这里 b.`name` is not null 不是一个必须的,是为了判断如果Department表没有这个部门就不算记录.
最后代码
select b.`Name` as `Department`, a.Name as Employee,Salary
from (
select
DepartmentId,
Name,
`Salary`,
(
select
count(distinct `Salary`)
from
`Employee` b
where
b.Salary>=a.Salary and a.`DepartmentId` = b.DepartmentId
) as `Rank`
from `Employee` a
)a left join `Department` b on a.DepartmentId = b.id
where
`rank` <= 3
and
b.`name` is not null;
-- 这里 b.`name` is not null 不是一个必须的,是为了判断如果Department表没有这个部门就不算记录.