Skip to content

Commit 1293612

Browse files
Added Popular Posts
1 parent da3eb9b commit 1293612

File tree

4 files changed

+350
-2
lines changed

4 files changed

+350
-2
lines changed

Popular Posts/README.md

Lines changed: 97 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,97 @@
1+
# Popular Posts
2+
![Star Badge](https://img.shields.io/static/v1?label=%F0%9F%8C%9F&message=If%20Useful&style=style=flat&color=BC4E99)
3+
[![View Main Folder](https://img.shields.io/badge/View-Main_Folder-971901?)](https://github.com/thecoddiwompler/SQL-Practice-Questions/tree/main)
4+
[![View Repositories](https://img.shields.io/badge/View-My_Repositories-blue?logo=GitHub)](https://github.com/thecoddiwompler?tab=repositories)
5+
[![View My Profile](https://img.shields.io/badge/View-My_Profile-green?logo=GitHub)](https://github.com/thecoddiwompler)
6+
7+
---
8+
9+
## 🛠️ Problem Statement
10+
11+
12+
<b>Table Name : post_views</b>
13+
</br>
14+
| Column Name |Type |
15+
| ------------- | ------------- |
16+
| session_id | int |
17+
| post_id | int |
18+
| perc_viewed | float |
19+
20+
<br>
21+
22+
<b>Table Name : user_sessions</b>
23+
</br>
24+
| Column Name |Type |
25+
| ------------- | ------------- |
26+
| session_id | int |
27+
| user_id | varchar(10) |
28+
| session_starttime | timestamp |
29+
| session_endtime | timestamp |
30+
| platform | varchar(20) |
31+
32+
The column 'perc_viewed' in the table 'post_views' denotes the percentage of the session duration time the user spent viewing a post. <b>
33+
Write a SQL query to calculate the total time that each post was viewed by users. Output post ID and the total viewing time in seconds, but only for posts with a total viewing time of over 5 seconds.
34+
35+
<details>
36+
<summary>
37+
Input
38+
</summary>
39+
40+
<b>Table Name : post_views</b>
41+
42+
| session_id | post_id | perc_viewed |
43+
|------------|---------|-------------|
44+
| 1 | 1 | 2 |
45+
| 1 | 2 | 4 |
46+
| 1 | 3 | 1 |
47+
| 2 | 1 | 20 |
48+
| 2 | 2 | 10 |
49+
| 2 | 3 | 10 |
50+
| 2 | 4 | 21 |
51+
| 3 | 2 | 1 |
52+
| 3 | 4 | 1 |
53+
| 4 | 2 | 50 |
54+
| 4 | 3 | 10 |
55+
| 6 | 2 | 2 |
56+
| 8 | 2 | 5 |
57+
| 8 | 3 | 2.5 |
58+
59+
60+
61+
<br/>
62+
63+
<b>Table Name : user_sessions
64+
65+
| session_id | user_id | session_starttime | session_endtime | platform |
66+
|------------|---------|----------------------|----------------------|----------|
67+
| 1 | U1 | 2020-01-01 12:14:28 | 2020-01-01 12:16:08 | Windows |
68+
| 2 | U1 | 2020-01-01 18:23:50 | 2020-01-01 18:24:00 | Windows |
69+
| 3 | U1 | 2020-01-01 08:15:00 | 2020-01-01 08:20:00 | IPhone |
70+
| 4 | U2 | 2020-01-01 10:53:10 | 2020-01-01 10:53:30 | IPhone |
71+
| 5 | U2 | 2020-01-01 18:25:14 | 2020-01-01 18:27:53 | IPhone |
72+
| 6 | U2 | 2020-01-01 11:28:13 | 2020-01-01 11:31:33 | Windows |
73+
| 7 | U3 | 2020-01-01 06:46:20 | 2020-01-01 06:58:13 | Android |
74+
| 8 | U3 | 2020-01-01 10:53:10 | 2020-01-01 10:53:50 | Android |
75+
| 9 | U3 | 2020-01-01 13:13:13 | 2020-01-01 13:34:34 | Windows |
76+
| 10 | U4 | 2020-01-01 08:12:00 | 2020-01-01 12:23:11 | Windows |
77+
| 11 | U4 | 2020-01-01 21:54:03 | 2020-01-01 21:54:04 | IPad |
78+
79+
80+
</details>
81+
82+
<details>
83+
<summary>
84+
Output
85+
</summary>
86+
87+
| post_id | total_viewtime |
88+
|------------|------------------------------|
89+
| 4 | 5.1 |
90+
| 2 | 24 |
91+
92+
93+
94+
</details>
95+
96+
---
97+

Popular Posts/schema.sql

Lines changed: 210 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,210 @@
1+
CREATE TABLE user_sessions (
2+
session_id int,
3+
user_id varchar(10),
4+
session_starttime timestamp,
5+
session_endtime timestamp,
6+
platform varchar(20)
7+
);
8+
9+
INSERT INTO
10+
user_sessions
11+
VALUES
12+
(
13+
1,
14+
'U1',
15+
'2020-01-01 12:14:28',
16+
'2020-01-01 12:16:08',
17+
'Windows'
18+
);
19+
20+
INSERT INTO
21+
user_sessions
22+
VALUES
23+
(
24+
2,
25+
'U1',
26+
'2020-01-01 18:23:50',
27+
'2020-01-01 18:24:00',
28+
'Windows'
29+
);
30+
31+
INSERT INTO
32+
user_sessions
33+
VALUES
34+
(
35+
3,
36+
'U1',
37+
'2020-01-01 08:15:00',
38+
'2020-01-01 08:20:00',
39+
'IPhone'
40+
);
41+
42+
INSERT INTO
43+
user_sessions
44+
VALUES
45+
(
46+
4,
47+
'U2',
48+
'2020-01-01 10:53:10',
49+
'2020-01-01 10:53:30',
50+
'IPhone'
51+
);
52+
53+
INSERT INTO
54+
user_sessions
55+
VALUES
56+
(
57+
5,
58+
'U2',
59+
'2020-01-01 18:25:14',
60+
'2020-01-01 18:27:53',
61+
'IPhone'
62+
);
63+
64+
INSERT INTO
65+
user_sessions
66+
VALUES
67+
(
68+
6,
69+
'U2',
70+
'2020-01-01 11:28:13',
71+
'2020-01-01 11:31:33',
72+
'Windows'
73+
);
74+
75+
INSERT INTO
76+
user_sessions
77+
VALUES
78+
(
79+
7,
80+
'U3',
81+
'2020-01-01 06:46:20',
82+
'2020-01-01 06:58:13',
83+
'Android'
84+
);
85+
86+
INSERT INTO
87+
user_sessions
88+
VALUES
89+
(
90+
8,
91+
'U3',
92+
'2020-01-01 10:53:10',
93+
'2020-01-01 10:53:50',
94+
'Android'
95+
);
96+
97+
INSERT INTO
98+
user_sessions
99+
VALUES
100+
(
101+
9,
102+
'U3',
103+
'2020-01-01 13:13:13',
104+
'2020-01-01 13:34:34',
105+
'Windows'
106+
);
107+
108+
INSERT INTO
109+
user_sessions
110+
VALUES
111+
(
112+
10,
113+
'U4',
114+
'2020-01-01 08:12:00',
115+
'2020-01-01 12:23:11',
116+
'Windows'
117+
);
118+
119+
INSERT INTO
120+
user_sessions
121+
VALUES
122+
(
123+
11,
124+
'U4',
125+
'2020-01-01 21:54:03',
126+
'2020-01-01 21:54:04',
127+
'IPad'
128+
);
129+
130+
COMMIT;
131+
132+
DROP TABLE IF EXISTS post_views;
133+
134+
CREATE TABLE post_views (
135+
session_id int,
136+
post_id int,
137+
perc_viewed float
138+
);
139+
140+
INSERT INTO
141+
post_views
142+
VALUES
143+
(1, 1, 2);
144+
145+
INSERT INTO
146+
post_views
147+
VALUES
148+
(1, 2, 4);
149+
150+
INSERT INTO
151+
post_views
152+
VALUES
153+
(1, 3, 1);
154+
155+
INSERT INTO
156+
post_views
157+
VALUES
158+
(2, 1, 20);
159+
160+
INSERT INTO
161+
post_views
162+
VALUES
163+
(2, 2, 10);
164+
165+
INSERT INTO
166+
post_views
167+
VALUES
168+
(2, 3, 10);
169+
170+
INSERT INTO
171+
post_views
172+
VALUES
173+
(2, 4, 21);
174+
175+
INSERT INTO
176+
post_views
177+
VALUES
178+
(3, 2, 1);
179+
180+
INSERT INTO
181+
post_views
182+
VALUES
183+
(3, 4, 1);
184+
185+
INSERT INTO
186+
post_views
187+
VALUES
188+
(4, 2, 50);
189+
190+
INSERT INTO
191+
post_views
192+
VALUES
193+
(4, 3, 10);
194+
195+
INSERT INTO
196+
post_views
197+
VALUES
198+
(6, 2, 2);
199+
200+
INSERT INTO
201+
post_views
202+
VALUES
203+
(8, 2, 5);
204+
205+
INSERT INTO
206+
post_views
207+
VALUES
208+
(8, 3, 2.5);
209+
210+
COMMIT;

Popular Posts/solution.sql

Lines changed: 40 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,40 @@
1+
WITH session_length AS (
2+
SELECT
3+
session_id,
4+
EXTRACT(
5+
SECOND
6+
FROM
7+
session_endtime - session_starttime
8+
) +(
9+
60 * EXTRACT(
10+
MINUTE
11+
FROM
12+
session_endtime - session_starttime
13+
)
14+
) +(
15+
3600 * EXTRACT(
16+
HOUR
17+
FROM
18+
session_endtime - session_starttime
19+
)
20+
) duration
21+
FROM
22+
user_sessions
23+
),
24+
post_views_timer AS (
25+
SELECT
26+
a.post_id,
27+
(a.perc_viewed * b.duration) / 100 viewtime
28+
FROM
29+
post_views a
30+
INNER JOIN session_length b ON a.session_id = b.session_id
31+
)
32+
SELECT
33+
post_id,
34+
SUM(viewtime) total_viewtime
35+
FROM
36+
post_views_timer
37+
GROUP BY
38+
post_id
39+
HAVING
40+
SUM(viewtime) > 5;

iqsql.md

Lines changed: 3 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -18,5 +18,6 @@
1818
18. Missing Invoices
1919
19. Odd and Even Measurements
2020
20. Onboarded Cities
21-
21. Qualifying Criteria
22-
22. Travel Analytics
21+
21. Popular Posts
22+
22. Qualifying Criteria
23+
23. Travel Analytics

0 commit comments

Comments
 (0)