Skip to content

Commit 324ec5d

Browse files
committed
solve: questions faizanxmulla#11, faizanxmulla#12
1 parent 61bac2f commit 324ec5d

File tree

2 files changed

+160
-0
lines changed

2 files changed

+160
-0
lines changed
Lines changed: 64 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,64 @@
1+
### Problem Statement
2+
3+
Write a query to print the highest and lowest salary of each employee in each department.
4+
5+
6+
### Schema Setup
7+
8+
```sql
9+
CREATE TABLE employee (
10+
emp_name VARCHAR(10),
11+
dep_id INT,
12+
salary INT
13+
);
14+
15+
DELETE FROM employee;
16+
17+
INSERT INTO employee VALUES
18+
('Siva', 1, 30000),
19+
('Ravi', 2, 40000),
20+
('Prasad', 1, 50000),
21+
('Sai', 2, 20000);
22+
```
23+
24+
25+
### Expected Output
26+
27+
dep_id | emp_name_max_salary | emp_name_min_salary |
28+
--|--|--|
29+
1 | Prasad | Siva |
30+
2 | Ravi | Sai |
31+
32+
33+
### Solution Query
34+
35+
```sql
36+
-- Solution 1: using two RANK() functions; and aggregation function w/ CASE WHEN // aslo my approach
37+
38+
WITH CTE as (
39+
SELECT *,
40+
RANK() OVER(PARTITION BY dep_id ORDER BY salary desc) as highest_rn,
41+
RANK() OVER(PARTITION BY dep_id ORDER BY salary) as lowest_rn
42+
FROM employee
43+
)
44+
SELECT dep_id,
45+
MAX(CASE WHEN highest_rn=1 THEN emp_name END) AS emp_name_max_salary,
46+
MAX(CASE WHEN lowest_rn=1 THEN emp_name END) AS emp_name_min_salary
47+
FROM CTE
48+
GROUP BY 1
49+
50+
51+
-- Solution 2: almost the same approach
52+
53+
WITH CTE as (
54+
SELECT dep_id, MAX(salary) as max_salary, MIN(salary) as min_salary
55+
FROM employee
56+
GROUP BY 1
57+
)
58+
SELECT dep_id,
59+
MAX(CASE WHEN salary=max_salary THEN emp_name ELSE NULL END) AS emp_name_max_salary,
60+
MAX(CASE WHEN salary=min_salary THEN emp_name ELSE NULL END) AS emp_name_min_salary
61+
FROM employee e JOIN CTE c USING(dep_id)
62+
GROUP BY 1
63+
ORDER BY 1
64+
```
Lines changed: 96 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,96 @@
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

Comments
 (0)