Skip to content

Commit cfe9835

Browse files
Added Consecutive User Logins
1 parent 83ea90c commit cfe9835

File tree

3 files changed

+192
-0
lines changed

3 files changed

+192
-0
lines changed

Consecutive User Logins/READme.md

Lines changed: 86 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,86 @@
1+
# Consecutive User Logins
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+
<b>Table Name : user_login</b>
12+
13+
| Column Name |Type |
14+
| ------------- | ------------- |
15+
| user_id | int |
16+
| login_date | date |
17+
18+
This table shows the date when each user logged in to the system. <br/><br>
19+
Write a SQL query to identify the users who logged in for 5 or more consecutive days. Return the user id, start date, end date, and no of consecutive days.
20+
<br><br>
21+
Please remember a user can login multiple times during a day but only consider users whose consecutive logins spanned 5 days or more.
22+
<br/>
23+
24+
The query result format is in the following example:
25+
26+
<details>
27+
<summary>
28+
Input
29+
</summary>
30+
<br>
31+
<b> Table Name: user_login <br><br>
32+
33+
| user_id | login_date |
34+
|---------|-------------|
35+
| 1 | 01/03/2024 |
36+
| 1 | 02/03/2024 |
37+
| 1 | 03/03/2024 |
38+
| 1 | 04/03/2024 |
39+
| 1 | 06/03/2024 |
40+
| 1 | 10/03/2024 |
41+
| 1 | 11/03/2024 |
42+
| 1 | 12/03/2024 |
43+
| 1 | 13/03/2024 |
44+
| 1 | 14/03/2024 |
45+
| 1 | 20/03/2024 |
46+
| 1 | 25/03/2024 |
47+
| 1 | 26/03/2024 |
48+
| 1 | 27/03/2024 |
49+
| 1 | 28/03/2024 |
50+
| 1 | 29/03/2024 |
51+
| 1 | 30/03/2024 |
52+
| 2 | 01/03/2024 |
53+
| 2 | 02/03/2024 |
54+
| 2 | 03/03/2024 |
55+
| 2 | 04/03/2024 |
56+
| 3 | 01/03/2024 |
57+
| 3 | 02/03/2024 |
58+
| 3 | 03/03/2024 |
59+
| 3 | 04/03/2024 |
60+
| 3 | 04/03/2024 |
61+
| 3 | 04/03/2024 |
62+
| 3 | 05/03/2024 |
63+
| 4 | 01/03/2024 |
64+
| 4 | 02/03/2024 |
65+
| 4 | 03/03/2024 |
66+
| 4 | 04/03/2024 |
67+
| 4 | 04/03/2024 |
68+
69+
70+
</details>
71+
72+
<details>
73+
<summary>
74+
Output <br><br>
75+
</summary>
76+
77+
| user_id | start_date | end_date | consecutive_days |
78+
|---------|------------|------------|------------------|
79+
| 1 | 2024-03-10 | 2024-03-14 | 5 |
80+
| 1 | 2024-03-25 | 2024-03-30 | 6 |
81+
| 3 | 2024-03-01 | 2024-03-05 | 5 |
82+
83+
84+
</details>
85+
86+
---

Consecutive User Logins/schema.sql

Lines changed: 43 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,43 @@
1+
drop table if exists user_login;
2+
3+
create table user_login
4+
(
5+
user_id int,
6+
login_date date
7+
);
8+
9+
INSERT INTO user_login (user_id, login_date)
10+
VALUES
11+
(1, to_date('01/03/2024','dd/mm/yyyy')),
12+
(1, to_date('02/03/2024','dd/mm/yyyy')),
13+
(1, to_date('03/03/2024','dd/mm/yyyy')),
14+
(1, to_date('04/03/2024','dd/mm/yyyy')),
15+
(1, to_date('06/03/2024','dd/mm/yyyy')),
16+
(1, to_date('10/03/2024','dd/mm/yyyy')),
17+
(1, to_date('11/03/2024','dd/mm/yyyy')),
18+
(1, to_date('12/03/2024','dd/mm/yyyy')),
19+
(1, to_date('13/03/2024','dd/mm/yyyy')),
20+
(1, to_date('14/03/2024','dd/mm/yyyy')),
21+
(1, to_date('20/03/2024','dd/mm/yyyy')),
22+
(1, to_date('25/03/2024','dd/mm/yyyy')),
23+
(1, to_date('26/03/2024','dd/mm/yyyy')),
24+
(1, to_date('27/03/2024','dd/mm/yyyy')),
25+
(1, to_date('28/03/2024','dd/mm/yyyy')),
26+
(1, to_date('29/03/2024','dd/mm/yyyy')),
27+
(1, to_date('30/03/2024','dd/mm/yyyy')),
28+
(2, to_date('01/03/2024','dd/mm/yyyy')),
29+
(2, to_date('02/03/2024','dd/mm/yyyy')),
30+
(2, to_date('03/03/2024','dd/mm/yyyy')),
31+
(2, to_date('04/03/2024','dd/mm/yyyy')),
32+
(3, to_date('01/03/2024','dd/mm/yyyy')),
33+
(3, to_date('02/03/2024','dd/mm/yyyy')),
34+
(3, to_date('03/03/2024','dd/mm/yyyy')),
35+
(3, to_date('04/03/2024','dd/mm/yyyy')),
36+
(3, to_date('04/03/2024','dd/mm/yyyy')),
37+
(3, to_date('04/03/2024','dd/mm/yyyy')),
38+
(3, to_date('05/03/2024','dd/mm/yyyy')),
39+
(4, to_date('01/03/2024','dd/mm/yyyy')),
40+
(4, to_date('02/03/2024','dd/mm/yyyy')),
41+
(4, to_date('03/03/2024','dd/mm/yyyy')),
42+
(4, to_date('04/03/2024','dd/mm/yyyy')),
43+
(4, to_date('04/03/2024','dd/mm/yyyy'));

Consecutive User Logins/solution.sql

Lines changed: 63 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,63 @@
1+
WITH distinct_user_login AS (
2+
SELECT
3+
DISTINCT user_id,
4+
login_date
5+
FROM
6+
user_login
7+
),
8+
ranked_user_login AS (
9+
SELECT
10+
user_id,
11+
login_date,
12+
rank() over(
13+
PARTITION by user_id
14+
ORDER BY
15+
login_date
16+
) rnk
17+
FROM
18+
distinct_user_login
19+
),
20+
all_consecutive_login AS (
21+
SELECT
22+
a.user_id,
23+
b.login_date start_date,
24+
a.login_date end_date
25+
FROM
26+
ranked_user_login a
27+
INNER JOIN ranked_user_login b ON a.login_date > b.login_date
28+
AND a.user_id = b.user_id
29+
AND a.login_date - b.login_date = a.rnk - b.rnk
30+
),
31+
filtered_start_date AS (
32+
SELECT
33+
user_id,
34+
start_date,
35+
max(end_date) end_date
36+
FROM
37+
all_consecutive_login
38+
GROUP BY
39+
user_id,
40+
start_date
41+
),
42+
filtered_end_date AS (
43+
SELECT
44+
user_id,
45+
min(start_date) start_date,
46+
end_date
47+
FROM
48+
filtered_start_date
49+
GROUP BY
50+
user_id,
51+
end_date
52+
)
53+
SELECT
54+
user_id,
55+
start_date,
56+
end_date,
57+
end_date - start_date + 1 consecutive_days
58+
FROM
59+
filtered_end_date
60+
WHERE
61+
end_date - start_date + 1 >= 5
62+
ORDER BY
63+
user_id;

0 commit comments

Comments
 (0)