diff --git a/src/main/kotlin/g3601_3700/s3611_find_overbooked_employees/readme.md b/src/main/kotlin/g3601_3700/s3611_find_overbooked_employees/readme.md new file mode 100644 index 00000000..c61b94e8 --- /dev/null +++ b/src/main/kotlin/g3601_3700/s3611_find_overbooked_employees/readme.md @@ -0,0 +1,103 @@ +3611\. Find Overbooked Employees + +Medium + +Table: `employees` + + +---------------+---------+ + | Column Name | Type | + +---------------+---------+ + | employee_id | int | + | employee_name | varchar | + | department | varchar | + +---------------+---------+ + employee_id is the unique identifier for this table. + Each row contains information about an employee and their department. + +Table: `meetings` + + +---------------+---------+ + | Column Name | Type | + +---------------+---------+ + | meeting_id | int | + | employee_id | int | + | meeting_date | date | + | meeting_type | varchar | + | duration_hours| decimal | + +---------------+---------+ + meeting_id is the unique identifier for this table. + Each row represents a meeting attended by an employee. meeting_type can be 'Team', 'Client', or 'Training'. + +Write a solution to find employees who are **meeting-heavy** - employees who spend more than `50%` of their working time in meetings during any given week. + +* Assume a standard work week is `40` **hours** +* Calculate **total meeting hours** per employee **per week** (**Monday to Sunday**) +* An employee is meeting-heavy if their weekly meeting hours `>` `20` hours (`50%` of `40` hours) +* Count how many weeks each employee was meeting-heavy +* **Only include** employees who were meeting-heavy for **at least** `2` **weeks** + +Return _the result table ordered by the number of meeting-heavy weeks in **descending** order, then by employee name in **ascending** order_. + +The result format is in the following example. + +**Example:** + +**Input:** + +employees table: + + +-------------+----------------+-------------+ + | employee_id | employee_name | department | + +-------------+----------------+-------------+ + | 1 | Alice Johnson | Engineering | + | 2 | Bob Smith | Marketing | + | 3 | Carol Davis | Sales | + | 4 | David Wilson | Engineering | + | 5 | Emma Brown | HR | + +-------------+----------------+-------------+ + +meetings table: + + +------------+-------------+--------------+--------------+----------------+ + | meeting_id | employee_id | meeting_date | meeting_type | duration_hours | + +------------+-------------+--------------+--------------+----------------+ + | 1 | 1 | 2023-06-05 | Team | 8.0 | + | 2 | 1 | 2023-06-06 | Client | 6.0 | + | 3 | 1 | 2023-06-07 | Training | 7.0 | + | 4 | 1 | 2023-06-12 | Team | 12.0 | + | 5 | 1 | 2023-06-13 | Client | 9.0 | + | 6 | 2 | 2023-06-05 | Team | 15.0 | + | 7 | 2 | 2023-06-06 | Client | 8.0 | + | 8 | 2 | 2023-06-12 | Training | 10.0 | + | 9 | 3 | 2023-06-05 | Team | 4.0 | + | 10 | 3 | 2023-06-06 | Client | 3.0 | + | 11 | 4 | 2023-06-05 | Team | 25.0 | + | 12 | 4 | 2023-06-19 | Client | 22.0 | + | 13 | 5 | 2023-06-05 | Training | 2.0 | + +------------+-------------+--------------+--------------+----------------+ + +**Output:** + + +-------------+---------------+-------------+---------------------+ + | employee_id | employee_name | department | meeting_heavy_weeks | + +-------------+---------------+-------------+---------------------+ + | 1 | Alice Johnson | Engineering | 2 | + | 4 | David Wilson | Engineering | 2 | + +-------------+---------------+-------------+---------------------+ + +**Explanation:** + +* **Alice Johnson (employee\_id = 1):** + * Week of June 5-11 (2023-06-05 to 2023-06-11): 8.0 + 6.0 + 7.0 = 21.0 hours (> 20 hours) + * Week of June 12-18 (2023-06-12 to 2023-06-18): 12.0 + 9.0 = 21.0 hours (> 20 hours) + * Meeting-heavy for 2 weeks +* **David Wilson (employee\_id = 4):** + * Week of June 5-11: 25.0 hours (> 20 hours) + * Week of June 19-25: 22.0 hours (> 20 hours) + * Meeting-heavy for 2 weeks +* **Employees not included:** + * Bob Smith (employee\_id = 2): Week of June 5-11: 15.0 + 8.0 = 23.0 hours (> 20), Week of June 12-18: 10.0 hours (< 20). Only 1 meeting-heavy week + * Carol Davis (employee\_id = 3): Week of June 5-11: 4.0 + 3.0 = 7.0 hours (< 20). No meeting-heavy weeks + * Emma Brown (employee\_id = 5): Week of June 5-11: 2.0 hours (< 20). No meeting-heavy weeks + +The result table is ordered by meeting\_heavy\_weeks in descending order, then by employee name in ascending order. \ No newline at end of file diff --git a/src/main/kotlin/g3601_3700/s3611_find_overbooked_employees/script.sql b/src/main/kotlin/g3601_3700/s3611_find_overbooked_employees/script.sql new file mode 100644 index 00000000..1f8e27d1 --- /dev/null +++ b/src/main/kotlin/g3601_3700/s3611_find_overbooked_employees/script.sql @@ -0,0 +1,32 @@ +# Write your MySQL query statement below +# #Medium #Database #2025_07_09_Time_516_ms_(100.00%)_Space_0.0_MB_(100.00%) +WITH process_1 AS ( + SELECT + employee_id, + SUM(duration_hours) AS duration_total + FROM + meetings + GROUP BY + employee_id, + WEEKOFYEAR(meeting_date), + YEAR(meeting_date) +) +SELECT + p.employee_id, + e.employee_name, + e.department, + COUNT(p.employee_id) AS meeting_heavy_weeks +FROM + process_1 p + INNER JOIN employees e ON p.employee_id = e.employee_id +WHERE + duration_total > 20 +GROUP BY + p.employee_id, + e.employee_name, + e.department +HAVING + COUNT(p.employee_id) > 1 +ORDER BY + meeting_heavy_weeks DESC, + employee_name ASC; diff --git a/src/test/kotlin/g3601_3700/s3611_find_overbooked_employees/MysqlTest.kt b/src/test/kotlin/g3601_3700/s3611_find_overbooked_employees/MysqlTest.kt new file mode 100644 index 00000000..7a4a1828 --- /dev/null +++ b/src/test/kotlin/g3601_3700/s3611_find_overbooked_employees/MysqlTest.kt @@ -0,0 +1,104 @@ +package g3601_3700.s3611_find_overbooked_employees + +import org.hamcrest.CoreMatchers.equalTo +import org.hamcrest.MatcherAssert.assertThat +import org.junit.jupiter.api.Test +import org.zapodot.junit.db.annotations.EmbeddedDatabase +import org.zapodot.junit.db.annotations.EmbeddedDatabaseTest +import org.zapodot.junit.db.common.CompatibilityMode +import java.io.BufferedReader +import java.io.FileNotFoundException +import java.io.FileReader +import java.sql.SQLException +import java.util.stream.Collectors +import javax.sql.DataSource + +@EmbeddedDatabaseTest( + compatibilityMode = CompatibilityMode.MySQL, + initialSqls = [ + ( + "CREATE TABLE employees (" + + " employee_id INTEGER," + + " employee_name VARCHAR(50)," + + " department VARCHAR(50)" + + ");" + + "INSERT INTO employees (employee_id, employee_name, department) VALUES" + + " (1, 'Alice Johnson', 'Engineering')," + + " (2, 'Bob Smith', 'Marketing')," + + " (3, 'Carol Davis', 'Sales')," + + " (4, 'David Wilson', 'Engineering')," + + " (5, 'Emma Brown', 'HR');" + + "CREATE TABLE meetings (" + + " meeting_id INTEGER," + + " employee_id INTEGER," + + " meeting_date DATE," + + " meeting_type VARCHAR(20)," + + " duration_hours DECIMAL(4,1)" + + ");" + + "INSERT INTO meetings (meeting_id, employee_id, " + + "meeting_date, meeting_type, duration_hours) VALUES" + + " (1, 1, '2023-06-05', 'Team', 8.0)," + + " (2, 1, '2023-06-06', 'Client', 6.0)," + + " (3, 1, '2023-06-07', 'Training', 7.0)," + + " (4, 1, '2023-06-12', 'Team', 12.0)," + + " (5, 1, '2023-06-13', 'Client', 9.0)," + + " (6, 2, '2023-06-05', 'Team', 15.0)," + + " (7, 2, '2023-06-06', 'Client', 8.0)," + + " (8, 2, '2023-06-12', 'Training', 10.0)," + + " (9, 3, '2023-06-05', 'Team', 4.0)," + + " (10, 3, '2023-06-06', 'Client', 3.0)," + + " (11, 4, '2023-06-05', 'Team', 25.0)," + + " (12, 4, '2023-06-19', 'Client', 22.0)," + + " (13, 5, '2023-06-05', 'Training', 2.0);" + ), + ], +) +internal class MysqlTest { + @Test + @Throws(SQLException::class, FileNotFoundException::class) + fun testScript(@EmbeddedDatabase dataSource: DataSource) { + dataSource.connection.use { connection -> + connection.createStatement().use { statement -> + statement.executeQuery( + BufferedReader( + FileReader( + ( + "src/main/kotlin/g3601_3700/" + + "s3611_find_overbooked_employees/" + + "script.sql" + ), + ), + ) + .lines() + .collect(Collectors.joining("\n")) + .replace("#.*?\\r?\\n".toRegex(), "") + .replace("WEEKOFYEAR", "ISO_WEEK"), + ).use { resultSet -> + assertThat(resultSet.next(), equalTo(true)) + assertThat(resultSet.getNString(1), equalTo("1")) + assertThat( + resultSet.getNString(2), + equalTo("Alice Johnson"), + ) + assertThat( + resultSet.getNString(3), + equalTo("Engineering"), + ) + assertThat(resultSet.getNString(4), equalTo("2")) + assertThat(resultSet.next(), equalTo(true)) + assertThat(resultSet.getNString(1), equalTo("4")) + assertThat( + resultSet.getNString(2), + equalTo("David Wilson"), + ) + assertThat( + resultSet.getNString(3), + equalTo("Engineering"), + ) + assertThat(resultSet.getNString(4), equalTo("2")) + assertThat(resultSet.next(), equalTo(false)) + } + } + } + } +}