|
| 1 | +### Problem Statement |
| 2 | + |
| 3 | +Write a query to get `start time` and the `end time` of each call from the below 2 tables. |
| 4 | + |
| 5 | +Also create a column of call duration in minutes. |
| 6 | + |
| 7 | +**NOTE:** Please do take into account there will be multiple calls from phone number and each entry in `start` table has a corresponding entry in the `end` table. |
| 8 | + |
| 9 | + |
| 10 | +### Schema Setup |
| 11 | + |
| 12 | +```sql |
| 13 | +CREATE TABLE call_start_logs( |
| 14 | + phone_number VARCHAR(10), |
| 15 | + start_time TIMESTAMP |
| 16 | +); |
| 17 | + |
| 18 | +CREATE TABLE call_end_logs( |
| 19 | + phone_number VARCHAR(10), |
| 20 | + end_time TIMESTAMP |
| 21 | +); |
| 22 | + |
| 23 | + |
| 24 | +INSERT INTO call_start_logs VALUES |
| 25 | +('PN1', '2022-01-01 10:20:00'), |
| 26 | +('PN1', '2022-01-01 16:25:00'), |
| 27 | +('PN2', '2022-01-01 12:30:00'), |
| 28 | +('PN3', '2022-01-02 10:00:00'), |
| 29 | +('PN3', '2022-01-02 12:30:00'), |
| 30 | +('PN3', '2022-01-03 09:20:00'); |
| 31 | + |
| 32 | +INSERT INTO call_end_logs VALUES |
| 33 | +('PN1', '2022-01-01 10:45:00'), |
| 34 | +('PN1', '2022-01-01 17:05:00'), |
| 35 | +('PN2', '2022-01-01 12:55:00'), |
| 36 | +('PN3', '2022-01-02 10:20:00'), |
| 37 | +('PN3', '2022-01-02 12:50:00'), |
| 38 | +('PN3', '2022-01-03 09:40:00'); |
| 39 | +``` |
| 40 | + |
| 41 | + |
| 42 | +### Expected Output |
| 43 | + |
| 44 | +phone_number | start_time | end_time | call_minutes | |
| 45 | +--|--|--|--| |
| 46 | +PN1 | 2022-01-01T10:20:00.000 | 2022-01-01T10:45:00.000 | 25.00 | |
| 47 | +PN1 | 2022-01-01T16:25:00.000 | 2022-01-01T17:05:00.000 | 40.00 | |
| 48 | +PN2 | 2022-01-01T12:30:00.000 | 2022-01-01T12:55:00.000 | 25.00 | |
| 49 | +PN3 | 2022-01-02T10:00:00.000 | 2022-01-02T10:20:00.000 | 20.00 | |
| 50 | +PN3 | 2022-01-02T12:30:00.000 | 2022-01-02T12:50:00.000 | 20.00 | |
| 51 | +PN3 | 2022-01-03T09:20:00.000 | 2022-01-03T09:40:00.000 | 20.00 | |
| 52 | + |
| 53 | + |
| 54 | +### Solution Query |
| 55 | + |
| 56 | +```sql |
| 57 | +-- Solution 1: using ROW_NUMBER() & JOIN // also my approach |
| 58 | + |
| 59 | +WITH start_logs_cte as ( |
| 60 | + SELECT *, |
| 61 | + ROW_NUMBER() OVER(PARTITION BY phone_number ORDER BY start_time) as start_rn |
| 62 | + FROM call_start_logs |
| 63 | +) |
| 64 | +, end_logs_cte as ( |
| 65 | + SELECT *, ROW_NUMBER() OVER(PARTITION BY phone_number ORDER BY end_time) as end_rn |
| 66 | + FROM call_end_logs |
| 67 | +) |
| 68 | +SELECT sl.phone_number, |
| 69 | + start_time, |
| 70 | + end_time, |
| 71 | + ROUND(EXTRACT(EPOCH FROM AGE(end_time, start_time)) / 60, 2) as call_minutes |
| 72 | +FROM start_logs_cte sl JOIN end_logs_cte el ON sl.start_rn=el.end_rn and sl.phone_number=el.phone_number |
| 73 | +ORDER BY 1, 2 |
| 74 | + |
| 75 | + |
| 76 | +-- Solution 2: using UNION ALL |
| 77 | + |
| 78 | +WITH CTE as ( |
| 79 | + SELECT phone_number, |
| 80 | + start_time as call_time, |
| 81 | + ROW_NUMBER() OVER(PARTITION BY phone_number ORDER BY start_time) as rn |
| 82 | + FROM call_start_logs |
| 83 | + UNION ALL |
| 84 | + SELECT phone_number, |
| 85 | + end_time as call_time, |
| 86 | + ROW_NUMBER() OVER(PARTITION BY phone_number ORDER BY end_time) as rn |
| 87 | + FROM call_end_logs |
| 88 | +) |
| 89 | +SELECT phone_number, |
| 90 | + MIN(call_time) as start_time, |
| 91 | + MAX(call_time) as end_time, |
| 92 | + ROUND(EXTRACT(EPOCH FROM AGE(MAX(call_time), MIN(call_time))) / 60, 2) as call_minutes |
| 93 | +FROM CTE |
| 94 | +GROUP BY phone_number, rn |
| 95 | +ORDER BY 1, 2 |
| 96 | +``` |
0 commit comments