Data Is A Precious Thing And Will Last Longer Than The Systems Themselves.
Sir Tim Berners-Lee (The inventor of the World Wide Web)
Question Source: LeetCode
Solution Language: MySQL
This Q&A series will cover data questions from LeetCode and present my solutions to them. Please feel free to comment with your suggestions if you feel that these problems may be solved in a more optimized manner.
Question (LeetCode Question #177, Level: Medium)
Write a SQL query to get the nth highest salary from the Employee
table.
+----+--------+ | Id | Salary | +----+--------+ | 1 | 100 | | 2 | 200 | | 3 | 300 | +----+--------+
For example, given the above Employee table, the nth highest salary where n = 2 is 200
. If there is no nth highest salary, then the query should return null
.
+------------------------+ | getNthHighestSalary(2) | +------------------------+ | 200 | +------------------------+
Solution
CREATE FUNCTION getNthHighestSalary(N INT) RETURNS INT
BEGIN
SET N = N-1;
RETURN (
Select
CASE when count(distinct Salary) <= N then null
else
(select distinct Salary
from Employee
order by Salary desc limit 1 offset N)
end
from Employee
);
END
NOTE:
- MySQL LIMIT and OFFSET syntax can only take numeric constants
- LIMIT 1 OFFSET N can also be written as LIMIT N,1
Question (LeetCode Question #184, Level: Medium)
The Employee
table holds all employees. Every employee has an Id, a salary, and there is also a column for the department Id.
+----+-------+--------+--------------+ | Id | Name | Salary | DepartmentId | +----+-------+--------+--------------+ | 1 | Joe | 70000 | 1 | | 2 | Jim | 90000 | 1 | | 3 | Henry | 80000 | 2 | | 4 | Sam | 60000 | 2 | | 5 | Max | 90000 | 1 | +----+-------+--------+--------------+
The Department
table holds all departments of the company.
+----+----------+ | Id | Name | +----+----------+ | 1 | IT | | 2 | Sales | +----+----------+
Write a SQL query to find employees who have the highest salary in each of the departments. For the above tables, your SQL query should return the following rows (order of rows does not matter).
+------------+----------+--------+ | Department | Employee | Salary | +------------+----------+--------+ | IT | Max | 90000 | | IT | Jim | 90000 | | Sales | Henry | 80000 | +------------+----------+--------+
Explanation:
Max and Jim both have the highest salary in the IT department and Henry has the highest salary in the Sales department.
Solution
Approach 1:
WITH temp AS
(SELECT d.Id, d.Name, MAX(e.Salary) AS Salary
FROM Employee e JOIN Department d
ON e.DepartmentId = d.Id
GROUP BY 1,2
)
SELECT temp.Name AS Department, Employee.Name AS Employee, Employee.Salary
FROM Employee JOIN temp
ON Employee.DepartmentId = temp.Id
WHERE Employee.Salary = temp.Salary;
Approach 2:
WITH temp AS (
SELECT DepartmentId, Name, Salary,
RANK() OVER (PARTITION BY DepartmentId ORDER BY Salary DESC) AS rnk
FROM Employee)
SELECT d.Name AS Department, temp.NAME AS Employee, temp.SALARY AS Salary
FROM temp
JOIN Department d
ON d.Id = temp.DepartmentId AND rnk = 1
Approach 3
SELECT Department, Employee, Salary
FROM (SELECT
d.Name AS Department,
e.Name AS Employee,
Salary,
RANK() OVER (PARTITION BY e.DepartmentId ORDER BY e.Salary DESC) AS rnk
FROM Employee e JOIN Department d
ON e.DepartmentId = d.Id) AS temp
WHERE rnk = 1
NOTE:
- Approach 2 and 3 use “Window Functions” to solve this problem.
- Window functions are used to optimize queries for efficiency and reduce query complexity when querying large datasets.
- To learn more about the Window functions used in MySQL 8.0, click here.
- Another source for learning about Window functions is Mode Analytics.