Skip to content

Commit e31e5c1

Browse files
authored
Added task 3482
1 parent b6205a0 commit e31e5c1

File tree

3 files changed

+235
-0
lines changed

3 files changed

+235
-0
lines changed
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,96 @@
1+
3482\. Analyze Organization Hierarchy
2+
3+
Hard
4+
5+
Table: `Employees`
6+
7+
+----------------+---------+
8+
| Column Name | Type |
9+
+----------------+---------+
10+
| employee_id | int |
11+
| employee_name | varchar |
12+
| manager_id | int |
13+
| salary | int |
14+
| department | varchar |
15+
+----------------+---------+
16+
employee_id is the unique key for this table.
17+
Each row contains information about an employee, including their ID, name, their manager's ID, salary, and department.
18+
manager_id is null for the top-level manager (CEO).
19+
20+
Write a solution to analyze the organizational hierarchy and answer the following:
21+
22+
1. **Hierarchy Levels:** For each employee, determine their level in the organization (CEO is level `1`, employees reporting directly to the CEO are level `2`, and so on).
23+
2. **Team Size:** For each employee who is a manager, count the total number of employees under them (direct and indirect reports).
24+
3. **Salary Budget:** For each manager, calculate the total salary budget they control (sum of salaries of all employees under them, including indirect reports, plus their own salary).
25+
26+
Return _the result table ordered by _the result ordered by **level** in **ascending** order, then by **budget** in **descending** order, and finally by **employee\_name** in **ascending** order_._
27+
28+
_The result format is in the following example._
29+
30+
**Example:**
31+
32+
**Input:**
33+
34+
Employees table:
35+
36+
+-------------+---------------+------------+--------+-------------+
37+
| employee_id | employee_name | manager_id | salary | department |
38+
+-------------+---------------+------------+--------+-------------+
39+
| 1 | Alice | null | 12000 | Executive |
40+
| 2 | Bob | 1 | 10000 | Sales |
41+
| 3 | Charlie | 1 | 10000 | Engineering |
42+
| 4 | David | 2 | 7500 | Sales |
43+
| 5 | Eva | 2 | 7500 | Sales |
44+
| 6 | Frank | 3 | 9000 | Engineering |
45+
| 7 | Grace | 3 | 8500 | Engineering |
46+
| 8 | Hank | 4 | 6000 | Sales |
47+
| 9 | Ivy | 6 | 7000 | Engineering |
48+
| 10 | Judy | 6 | 7000 | Engineering |
49+
+-------------+---------------+------------+--------+-------------+
50+
51+
**Output:**
52+
53+
+-------------+---------------+-------+-----------+--------+
54+
| employee_id | employee_name | level | team_size | budget |
55+
+-------------+---------------+-------+-----------+--------+
56+
| 1 | Alice | 1 | 9 | 84500 |
57+
| 3 | Charlie | 2 | 4 | 41500 |
58+
| 2 | Bob | 2 | 3 | 31000 |
59+
| 6 | Frank | 3 | 2 | 23000 |
60+
| 4 | David | 3 | 1 | 13500 |
61+
| 7 | Grace | 3 | 0 | 8500 |
62+
| 5 | Eva | 3 | 0 | 7500 |
63+
| 9 | Ivy | 4 | 0 | 7000 |
64+
| 10 | Judy | 4 | 0 | 7000 |
65+
| 8 | Hank | 4 | 0 | 6000 |
66+
+-------------+---------------+-------+-----------+--------+
67+
68+
**Explanation:**
69+
70+
* **Organization Structure:**
71+
* Alice (ID: 1) is the CEO (level 1) with no manager
72+
* Bob (ID: 2) and Charlie (ID: 3) report directly to Alice (level 2)
73+
* David (ID: 4), Eva (ID: 5) report to Bob, while Frank (ID: 6) and Grace (ID: 7) report to Charlie (level 3)
74+
* Hank (ID: 8) reports to David, and Ivy (ID: 9) and Judy (ID: 10) report to Frank (level 4)
75+
* **Level Calculation:**
76+
* The CEO (Alice) is at level 1
77+
* Each subsequent level of management adds 1 to the level
78+
* **Team Size Calculation:**
79+
* Alice has 9 employees under her (the entire company except herself)
80+
* Bob has 3 employees (David, Eva, and Hank)
81+
* Charlie has 4 employees (Frank, Grace, Ivy, and Judy)
82+
* David has 1 employee (Hank)
83+
* Frank has 2 employees (Ivy and Judy)
84+
* Eva, Grace, Hank, Ivy, and Judy have no direct reports (team\_size = 0)
85+
* **Budget Calculation:**
86+
* Alice's budget: Her salary (12000) + all employees' salaries (72500) = 84500
87+
* Charlie's budget: His salary (10000) + Frank's budget (23000) + Grace's salary (8500) = 41500
88+
* Bob's budget: His salary (10000) + David's budget (13500) + Eva's salary (7500) = 31000
89+
* Frank's budget: His salary (9000) + Ivy's salary (7000) + Judy's salary (7000) = 23000
90+
* David's budget: His salary (7500) + Hank's salary (6000) = 13500
91+
* Employees with no direct reports have budgets equal to their own salary
92+
93+
**Note:**
94+
95+
* The result is ordered first by level in ascending order
96+
* Within the same level, employees are ordered by budget in descending order then by name in ascending order
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,43 @@
1+
# Write your MySQL query statement below
2+
# #Hard #Database #2025_03_11_Time_712_ms_(100.00%)_Space_0.0_MB_(100.00%)
3+
with recursive org_hierarchy(orig_employee_id, orig_employee_name, employee_id, employee_name, manager_id, salary, org_level) as
4+
(
5+
select employee_id as orig_employee_id,
6+
employee_name as orig_employee_name,
7+
employee_id,
8+
employee_name,
9+
manager_id,
10+
salary,
11+
1 as org_level
12+
from Employees
13+
UNION ALL
14+
select P.orig_employee_id,
15+
P.orig_employee_name,
16+
CH.employee_id,
17+
CH.employee_name,
18+
CH.manager_id,
19+
CH.salary,
20+
P.org_level + 1
21+
from org_hierarchy P, Employees CH
22+
where ch.manager_id = P.employee_id
23+
),
24+
CEO_hierarchy as (
25+
select org_hierarchy.employee_id as SUB_employee_id,
26+
org_hierarchy.employee_name,
27+
org_hierarchy.org_level as sub_level
28+
from org_hierarchy, Employees
29+
where org_hierarchy.orig_employee_id = Employees.employee_id
30+
and Employees.manager_id is null
31+
)
32+
select
33+
org_hierarchy.ORIG_EMPLOYEE_ID as employee_id,
34+
org_hierarchy.ORIG_EMPLOYEE_name as employee_name,
35+
CEO_hierarchy.sub_level as "level",
36+
count(*) - 1 as team_size,
37+
sum(org_hierarchy.salary) as budget
38+
from org_hierarchy, CEO_hierarchy
39+
where org_hierarchy.ORIG_EMPLOYEE_ID = CEO_hierarchy.SUB_employee_id
40+
group by org_hierarchy.ORIG_EMPLOYEE_ID,
41+
org_hierarchy.ORIG_EMPLOYEE_name,
42+
CEO_hierarchy.sub_level
43+
order by 3 asc, 5 desc, 2
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,96 @@
1+
package g3401_3500.s3482_analyze_organization_hierarchy
2+
3+
import org.hamcrest.CoreMatchers.equalTo
4+
import org.hamcrest.MatcherAssert.assertThat
5+
import org.junit.jupiter.api.Test
6+
import org.zapodot.junit.db.annotations.EmbeddedDatabase
7+
import org.zapodot.junit.db.annotations.EmbeddedDatabaseTest
8+
import org.zapodot.junit.db.common.CompatibilityMode
9+
import java.io.BufferedReader
10+
import java.io.FileNotFoundException
11+
import java.io.FileReader
12+
import java.sql.ResultSet
13+
import java.sql.SQLException
14+
import java.util.stream.Collectors
15+
import javax.sql.DataSource
16+
17+
@EmbeddedDatabaseTest(
18+
compatibilityMode = CompatibilityMode.MySQL,
19+
initialSqls = [
20+
(
21+
" CREATE TABLE Employees (" +
22+
" employee_id INT," +
23+
" employee_name VARCHAR(50)," +
24+
" manager_id INT," +
25+
" salary INT," +
26+
" department VARCHAR(100)" +
27+
");" +
28+
"insert into Employees (employee_id, employee_name, manager_id, salary, department) values " +
29+
"(1, 'Alice', NULL, 12000, 'Executive');" +
30+
"insert into Employees (employee_id, employee_name, manager_id, salary, department) values " +
31+
"(2, 'Bob', 1, 10000, 'Sales');" +
32+
"insert into Employees (employee_id, employee_name, manager_id, salary, department) values " +
33+
"(3, 'Charlie', 1, 10000, 'Engineering');" +
34+
"insert into Employees (employee_id, employee_name, manager_id, salary, department) values " +
35+
"(4, 'David', 2, 7500, 'Sales');" +
36+
"insert into Employees (employee_id, employee_name, manager_id, salary, department) values " +
37+
"(5, 'Eva', 2, 7500, 'Sales');" +
38+
"insert into Employees (employee_id, employee_name, manager_id, salary, department) values " +
39+
"(6, 'Frank', 3, 9000, 'Engineering');" +
40+
"insert into Employees (employee_id, employee_name, manager_id, salary, department) values " +
41+
"(7, 'Grace', 3, 8500, 'Engineering');" +
42+
"insert into Employees (employee_id, employee_name, manager_id, salary, department) values " +
43+
"(8, 'Hank', 4, 6000, 'Sales');" +
44+
"insert into Employees (employee_id, employee_name, manager_id, salary, department) values " +
45+
"(9, 'Ivy', 6, 7000, 'Engineering');" +
46+
"insert into Employees (employee_id, employee_name, manager_id, salary, department) values " +
47+
"(10, 'Judy', 6, 7000, 'Engineering');"
48+
),
49+
],
50+
)
51+
internal class MysqlTest {
52+
@Test
53+
@Throws(SQLException::class, FileNotFoundException::class)
54+
fun testScript(@EmbeddedDatabase dataSource: DataSource) {
55+
dataSource.connection.use { connection ->
56+
connection.createStatement().use { statement ->
57+
statement.executeQuery(
58+
BufferedReader(
59+
FileReader(
60+
(
61+
"src/main/kotlin/g3401_3500/" +
62+
"s3482_analyze_organization_hierarchy/" +
63+
"script.sql"
64+
),
65+
),
66+
)
67+
.lines()
68+
.collect(Collectors.joining("\n"))
69+
.replace("#.*?\\r?\\n".toRegex(), ""),
70+
).use { resultSet ->
71+
checkRow(resultSet, arrayOf<String>("1", "Alice", "1", "9", "84500"))
72+
checkRow(resultSet, arrayOf<String>("3", "Charlie", "2", "4", "41500"))
73+
checkRow(resultSet, arrayOf<String>("2", "Bob", "2", "3", "31000"))
74+
checkRow(resultSet, arrayOf<String>("6", "Frank", "3", "2", "23000"))
75+
checkRow(resultSet, arrayOf<String>("4", "David", "3", "1", "13500"))
76+
checkRow(resultSet, arrayOf<String>("7", "Grace", "3", "0", "8500"))
77+
checkRow(resultSet, arrayOf<String>("5", "Eva", "3", "0", "7500"))
78+
checkRow(resultSet, arrayOf<String>("9", "Ivy", "4", "0", "7000"))
79+
checkRow(resultSet, arrayOf<String>("10", "Judy", "4", "0", "7000"))
80+
checkRow(resultSet, arrayOf<String>("8", "Hank", "4", "0", "6000"))
81+
assertThat<Boolean>(resultSet.next(), equalTo<Boolean>(false))
82+
}
83+
}
84+
}
85+
}
86+
87+
@Throws(SQLException::class)
88+
private fun checkRow(resultSet: ResultSet, values: Array<String>) {
89+
assertThat<Boolean>(resultSet.next(), equalTo<Boolean>(true))
90+
assertThat<String>(resultSet.getNString(1), equalTo<String>(values[0]))
91+
assertThat<String>(resultSet.getNString(2), equalTo<String>(values[1]))
92+
assertThat<String>(resultSet.getNString(3), equalTo<String>(values[2]))
93+
assertThat<String>(resultSet.getNString(4), equalTo<String>(values[3]))
94+
assertThat<String>(resultSet.getNString(5), equalTo<String>(values[4]))
95+
}
96+
}

0 commit comments

Comments
 (0)