蚂蚁面试SQL—分层贪心招聘问题
题目描述
某互联网大厂在进行员工招聘,给定固定的薪资预算【12万】,公司制定了如下贪心招聘策略:
- 优先招聘 高职级员工(P7>P6>P5)
- 在同一职级内,优先招聘期望薪资更低的候选人
- 在满足高职级招聘人数尽可能多的前提下,再考虑低职级
- 总招聘薪资不能超过预算
数据模拟
CREATE TABLE dwd_emp_candidate_di (
candidate_id VARCHAR(20) COMMENT '候选者ID',
level VARCHAR(20) COMMENT '应聘职级',
salary DOUBLE COMMENT '预期薪资(单位:万)'
);
INSERT INTO dwd_emp_candidate_di VALUES
('001', 'P6', 2.5),
('002', 'P6', 2.5),
('003', 'P7', 5.0),
('004', 'P7', 4.5),
('005', 'P7', 4.0),
('006', 'P6', 3.0),
('007', 'P5', 2.0),
('008', 'P5', 1.8);
思路分析
- 本题本质上是一个 带有优先级约束的贪心选择问题
- 首先将P7员工按照薪资排序,优先招聘工资较低的员工,确保不会超过预算,计算剩余预算
- 然后再将P6员工按照薪资排序,优先招聘工资较低的员工,确保不会超过上述剩余预算,计算剩余预算
- 以此类推
参考答案
WITH
p7_ranked AS (
SELECT
candidate_id,
level,
salary,
SUM(salary) OVER (ORDER BY salary) AS running_salary,
row_number() over (ORDER BY salary) AS rk
FROM dwd_emp_candidate_di
WHERE level = 'P7'
),
p7_hired AS (
SELECT *
FROM p7_ranked
WHERE running_salary <= 12
),
p7_budget AS (
SELECT COALESCE(SUM(salary), 0) AS used_budget
FROM p7_hired
),
p6_ranked AS (
SELECT
candidate_id,
level,
salary,
SUM(salary) OVER (ORDER BY salary) AS running_salary
FROM dwd_emp_candidate_di
WHERE level = 'P6'
),
p6_hired AS (
SELECT p6.*
FROM p6_ranked p6
JOIN p7_budget b
ON 1 = 1
WHERE p6.running_salary <= (12 - b.used_budget)
),
p6_budget AS (
SELECT COALESCE(SUM(salary), 0) AS used_budget
FROM p6_hired
),
p5_ranked AS (
SELECT
candidate_id,
level,
salary,
SUM(salary) OVER (ORDER BY salary) AS running_salary
FROM dwd_emp_candidate_di
WHERE level = 'P5'
),
p5_hired AS (
SELECT p5.*
FROM p5_ranked p5
JOIN p7_budget b7
ON 1 = 1
JOIN p6_budget b6
ON 1 = 1
WHERE p5.running_salary <= (12 - b7.used_budget - b6.used_budget)
)
SELECT candidate_id, level, salary FROM p7_hired
UNION ALL
SELECT candidate_id, level, salary FROM p6_hired
UNION ALL
SELECT candidate_id, level, salary FROM p5_hired;

大厂高频面试SQL题 文章被收录于专栏
收录字节、阿里、蚂蚁、美团、京东、百度、小红书、拼多多等大厂面试SQL题