공장 내 여러 머신이 여러 개의 프로세스를 처리하며, 각 프로세스는 시작(start)과 종료(end) 시각을 갖고 있습니다. 각 머신별 평균 처리 시간(end - start)을 계산해야 합니다.
Table: Activity
+----------------+---------+
| Column Name | Type |
+----------------+---------+
| machine_id | int |
| process_id | int |
| activity_type | enum |
| timestamp | float |
+----------------+---------+
The table shows the user activities for a factory website.
(machine_id, process_id, activity_type) is the primary key (combination of columns with unique values) of this table.
machine_id is the ID of a machine.
process_id is the ID of a process running on the machine with ID machine_id.
activity_type is an ENUM (category) of type ('start', 'end').
timestamp is a float representing the current time in seconds.
'start' means the machine starts the process at the given timestamp and 'end' means the machine ends the process at the given timestamp.
The 'start' timestamp will always be before the 'end' timestamp for every (machine_id, process_id) pair.
It is guaranteed that each (machine_id, process_id) pair has a 'start' and 'end' timestamp.
There is a factory website that has several machines each running the same number of processes. Write a solution to find the average time each machine takes to complete a process.
The time to complete a process is the 'end' timestamp minus the 'start' timestamp. The average time is calculated by the total time to complete every process on the machine divided by the number of processes that were run.
The resulting table should have the machine_id along with the average time as processing_time, which should be rounded to 3 decimal places.
Return the result table in any order.
The result format is in the following example.
Example 1:
Input:
Activity table:
+------------+------------+---------------+-----------+
| machine_id | process_id | activity_type | timestamp |
+------------+------------+---------------+-----------+
| 0 | 0 | start | 0.712 |
| 0 | 0 | end | 1.520 |
| 0 | 1 | start | 3.140 |
| 0 | 1 | end | 4.120 |
| 1 | 0 | start | 0.550 |
| 1 | 0 | end | 1.550 |
| 1 | 1 | start | 0.430 |
| 1 | 1 | end | 1.420 |
| 2 | 0 | start | 4.100 |
| 2 | 0 | end | 4.512 |
| 2 | 1 | start | 2.500 |
| 2 | 1 | end | 5.000 |
+------------+------------+---------------+-----------+
Output:
+------------+-----------------+
| machine_id | processing_time |
+------------+-----------------+
| 0 | 0.894 |
| 1 | 0.995 |
| 2 | 1.456 |
+------------+-----------------+
Explanation:
There are 3 machines running 2 processes each.
Machine 0's average time is ((1.520 - 0.712) + (4.120 - 3.140)) / 2 = 0.894
Machine 1's average time is ((1.550 - 0.550) + (1.420 - 0.430)) / 2 = 0.995
Machine 2's average time is ((4.512 - 4.100) + (5.000 - 2.500)) / 2 = 1.456
Step 1: 같은 process_id에 대해 start와 end를 짝짓기
Activity 테이블에 start와 end가 다른 행에 존재합니다. 우리는 한 줄에 두 정보를 포함시키고 싶습니다. 셀프 조인을 통해 같은 테이블을 두 번 사용해서 start 행과 end 행을 짝지어줘야 합니다.
SELECT A1.machine_id, A1.process_id, A1.timestamp AS start_time, A2.timestamp AS end_time
FROM Activity A1
JOIN Activity A2
ON A1.machine_id = A2.machine_id
AND A1.process_id = A2.process_id
AND A1.activity_type = 'start'
AND A2.activity_type = 'end';
| machine_id | process_id | start_time | end_time |
| ---------- | ---------- | ---------- | -------- |
| 0 | 0 | 0.712 | 1.52 |
| 0 | 1 | 3.14 | 4.12 |
| 1 | 0 | 0.55 | 1.55 |
| 1 | 1 | 0.43 | 1.42 |
| 2 | 0 | 4.1 | 4.512 |
| 2 | 1 | 2.5 | 5 |
각 process의 시작시간과 종료시간이 한 줄에 들어갑니다.
Step 2: 수행 시간 계산
여기서 end_time - start_time 하면 하나의 프로세스 수행 시간이 나옵니다.
SELECT A1.machine_id, A1.process_id, A1.timestamp AS start_time, A2.timestamp AS end_time, A2.timestamp - A1.timestamp AS processing_time
FROM Activity A1
JOIN Activity A2
ON A1.machine_id = A2.machine_id
AND A1.process_id = A2.process_id
AND A1.activity_type = 'start'
AND A2.activity_type = 'end';
| machine_id | process_id | start_time | end_time | processing_time |
| ---------- | ---------- | ---------- | -------- | ------------------ |
| 0 | 0 | 0.712 | 1.52 | 0.8079999685287476 |
| 0 | 1 | 3.14 | 4.12 | 0.9799997806549072 |
| 1 | 0 | 0.55 | 1.55 | 0.9999999403953552 |
| 1 | 1 | 0.43 | 1.42 | 0.9899999499320984 |
| 2 | 0 | 4.1 | 4.512 | 0.4120001792907715 |
| 2 | 1 | 2.5 | 5 | 2.5 |
Step 3: 머신별 평균 수행 시간 구하기
이제 machine_id로 GROUP BY 해서 평균을 내면 됩니다.
SELECT A1.machine_id, ROUND(AVG(A2.timestamp - A1.timestamp), 3) AS processing_time
FROM Activity A1
JOIN Activity A2
ON A1.machine_id = A2.machine_id
AND A1.process_id = A2.process_id
AND A1.activity_type = 'start'
AND A2.activity_type = 'end'
GROUP BY A1.machine_id;
'Computer Science > SQL' 카테고리의 다른 글
SQL | LeetCode 570. 직속 부하 직원이 5명 이상인 매니저 찾기 (0) | 2025.05.04 |
---|---|
SQL | LeetCode 1280. Nested Join (1) | 2025.05.04 |
SQL | LeetCode 197. 셀프 조인(Self Join)과 DATE_ADD를 활용한 날짜 비교 문제 (0) | 2025.05.02 |
SQL | LeetCode 1581. 방문은 했지만 거래는 없던 고객 찾기 (RIGHT JOIN & GROUP BY 예제) (2) | 2025.05.01 |
SQL | LeetCode 1683. 문자열 길이 함수 (1) | 2025.04.30 |