问题
下面是某游戏公司记录的用户每日登录数据, 计算每个用户最大的连续登录天数,定义连续登录时可以间隔一天。举例:如果一个用户在 1,3,5,6,9 登录了游戏,则视为连续 6 天登录。
user_id dt
1001 2021-12-12
1002 2021-12-12
1001 2021-12-13
1001 2021-12-14
1001 2021-12-16
1002 2021-12-16
1001 2021-12-19
1002 2021-12-17
1001 2021-12-20
解答
这是个连续问题的升级版,当满足某种要求时我们也是算作连续的,所以不能使用传统的连续编号,然后做差值的解法了。
核心思路解析如下:
登录日期 | 第一步:上一个日期 | 第二步:判断登录日期与上一个日期差值是否在2之内 | 第三步:然后根据标记开窗做sum |
---|---|---|---|
1 | 1 | 0 | 0 |
3 | 1 | 0 | 0 |
5 | 3 | 0 | 0 |
6 | 5 | 0 | 0 |
9 | 6 | 1 | 1 |
11 | 9 | 0 | 1 |
with temp as (
select '1001' as user_id , '2021-12-12' as dt
union all
select '1002' as user_id , '2021-12-12' as dt
union all
select '1001' as user_id , '2021-12-13' as dt
union all
select '1001' as user_id , '2021-12-14' as dt
union all
select '1001' as user_id , '2021-12-16' as dt
union all
select '1002' as user_id , '2021-12-16' as dt
union all
select '1001' as user_id , '2021-12-19' as dt
union all
select '1002' as user_id , '2021-12-17' as dt
union all
select '1001' as user_id , '2021-12-20' as dt
)
select
user_id
,max(diff) as max_login_days
from
( select
user_id
,user_group
,datediff(max(dt),min(dt))+1 as diff --拿到每个用户下,连续时间里面最大日期与最小日期的差值加1就得到来连续天数
from
(
select
user_id
,dt
-- 如果当前日期与上一个日期的差值在2之内,那么就给0,否则给1
,sum(if(datediff(dt,last_dt)<=2,0,1)) over(partition by user_id order by dt) as user_group
from
(
select
user_id
,dt
,lag(dt,1,dt) over(partition by user_id order by dt) as last_dt --根据user_id分组,拿到当前行的上一个日期,没有上一个就给自己本身的值
from temp
)t1
)t1
group by user_id ,user_group
)t1
group by user_id
;
Comments NOTHING