Skip to content

Commit 662354f

Browse files
author
Indrajeet Mishra
committed
Added a new question- Average Salary: Departments Vs Company
1 parent f2742c9 commit 662354f

File tree

3 files changed

+161
-0
lines changed

3 files changed

+161
-0
lines changed
Lines changed: 93 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,93 @@
1+
# [Average Salary: Departments VS Company](https://leetcode.com/problems/average-salary-departments-vs-company/)
2+
![Star Badge](https://img.shields.io/static/v1?label=%F0%9F%8C%9F&message=If%20Useful&style=style=flat&color=BC4E99)
3+
[![View Main Folder](https://img.shields.io/badge/View-Main_Folder-971901?)](https://github.com/thecoddiwompler/SQL-Practice-Questions/tree/main)
4+
[![View Repositories](https://img.shields.io/badge/View-My_Repositories-blue?logo=GitHub)](https://github.com/thecoddiwompler?tab=repositories)
5+
[![View My Profile](https://img.shields.io/badge/View-My_Profile-green?logo=GitHub)](https://github.com/thecoddiwompler)
6+
7+
---
8+
9+
## 🛠️ Problem Statement
10+
11+
<b>Table Name : Salary</b>
12+
13+
| Column Name |Type |
14+
| ------------- | ------------- |
15+
| id | int |
16+
| employee_id | int |
17+
| amount | int |
18+
| pay_date | date |
19+
20+
* id is the primary key column for this table. Each row of this table indicates the salary of an employee in one month.
21+
* employee_id is a foreign key from the Employee table.
22+
</br>
23+
24+
<b>Table Name : Employee</b>
25+
26+
| Column Name |Type |
27+
| ------------- | ------------- |
28+
| employee_id | int |
29+
| department_id | int |
30+
31+
* employee_id is the primary key column for this table. Each row of this table indicates the department of an employee.
32+
33+
</br>
34+
Write an SQL query to report the comparison result (higher/lower/same) of the average salary of employees
35+
in a department to the company’s average salary. Return the result table in any order.
36+
37+
The query result format is in the following example.
38+
</br>
39+
</br>
40+
<details>
41+
<summary>
42+
Input
43+
</summary>
44+
</br>
45+
46+
<b> Table Name: Salary </b></br>
47+
48+
| id | employee_id | amount | pay_date |
49+
| --------- | ------------- | ------ | --------- |
50+
| 1 | 1 | 9000 | 2017/03/31 |
51+
| 2 | 2 | 6000 | 2017/03/31 |
52+
| 3 | 3 | 10000 | 2017/03/31 |
53+
| 4 | 1 | 7000 | 2017/02/28 |
54+
| 5 | 2 | 6000 | 2017/02/28 |
55+
| 6 | 3 | 8000 | 2017/02/28 |
56+
57+
<b> Table Name: Employee </b></br>
58+
59+
| employee_id | department_id |
60+
|----|-------|
61+
| 1 | 1 |
62+
| 2 | 2 |
63+
| 3 | 2 |
64+
65+
</details>
66+
67+
<details>
68+
<summary>
69+
Output
70+
</summary>
71+
</br>
72+
73+
| pay_month | department_id | comparison |
74+
| --- |--- | --- |
75+
| 2017-02 | 1 | same |
76+
| 2017-03 | 1 | higher |
77+
| 2017-02 | 2 | same |
78+
| 2017-03 | 2 | lower |
79+
</details>
80+
81+
<br>
82+
<b> Explanation: </b>
83+
84+
- In March, the company's average salary is (9000+6000+10000)/3 = 8333.33...
85+
- The average salary for department '1' is 9000, which is the salary of employee_id '1' since there is only
86+
one employee in this department. So the comparison result is 'higher' since 9000 > 8333.33 obviously.
87+
- The average salary of department '2' is (6000 + 10000)/2 = 8000, which is the average of employee_id '2' and '3'.
88+
So the comparison result is 'lower' since 8000 < 8333.33.
89+
90+
With the same formula for the average salary comparison in February, the result is 'same' since both the department
91+
'1' and '2' have the same average salary with the company, which is 7000.
92+
93+
---
Lines changed: 33 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,33 @@
1+
-- Create the 'salary' table
2+
CREATE TABLE IF NOT EXISTS salary (
3+
id INT,
4+
employee_id INT,
5+
amount INT,
6+
pay_date DATE
7+
);
8+
9+
-- Insert data into the 'salary' table
10+
INSERT INTO
11+
salary (id, employee_id, amount, pay_date)
12+
VALUES
13+
(1, 1, 9000, '2017-03-31'),
14+
(2, 2, 6000, '2017-03-31'),
15+
(3, 3, 10000, '2017-03-31'),
16+
(4, 1, 7000, '2017-02-28'),
17+
(5, 2, 6000, '2017-02-28'),
18+
(6, 3, 8000, '2017-02-28');
19+
20+
COMMIT;
21+
22+
-- Create the 'employee' table
23+
CREATE TABLE IF NOT EXISTS employee (employee_id INT, department_id INT);
24+
25+
-- Insert data into the 'employee' table
26+
INSERT INTO
27+
employee (employee_id, department_id)
28+
VALUES
29+
(1, 1),
30+
(2, 2),
31+
(3, 2);
32+
33+
COMMIT;
Lines changed: 35 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,35 @@
1+
WITH company_avg AS (
2+
SELECT
3+
to_char(pay_date, 'YYYY-MM') pay_month,
4+
AVG(amount) company_avg
5+
FROM
6+
salary
7+
GROUP BY
8+
to_char(pay_date, 'YYYY-MM')
9+
),
10+
department_avg AS (
11+
SELECT
12+
to_char(a.pay_date, 'YYYY-MM') pay_month,
13+
b.department_id,
14+
AVG(a.amount) department_avg
15+
FROM
16+
salary a
17+
INNER JOIN employee b ON a.employee_id = b.employee_id
18+
GROUP BY
19+
to_char(a.pay_date, 'YYYY-MM'),
20+
b.department_id
21+
)
22+
SELECT
23+
a.pay_month,
24+
b.department_id,
25+
CASE
26+
WHEN b.department_avg > a.company_avg THEN 'higher'
27+
WHEN b.department_avg < a.company_avg THEN 'lower'
28+
ELSE 'same'
29+
END AS comparison
30+
FROM
31+
company_avg a
32+
INNER JOIN department_avg b ON a.pay_month = b.pay_month
33+
ORDER BY
34+
department_id,
35+
pay_month;

0 commit comments

Comments
 (0)