Skip to content

SQL163 每篇文章同一时刻最大在看人数

Static BadgeStatic BadgeStatic Badge

Important

同时在线人数问题:(进入时间,人数+1) UNION [ALL] (离开时间,人数-1)

题目描述

用户行为日志表tb_user_log

iduidartical_idin_timeout_timesign_cin
110190012021-11-01 10:00:002021-11-01 10:00:110
210290012021-11-01 10:00:092021-11-01 10:00:380
310390012021-11-01 10:00:282021-11-01 10:00:580
410490022021-11-01 11:00:452021-11-01 11:01:110
510590012021-11-01 10:00:512021-11-01 10:00:590
610690022021-11-01 11:00:552021-11-01 11:01:240
710790012021-11-01 10:00:012021-11-01 10:01:500

(uid-用户ID, artical_id-文章ID, in_time-进入时间, out_time-离开时间, sign_in-是否签到)

场景逻辑说明artical_id-文章ID代表用户浏览的文章的ID,artical_id-文章ID0表示用户在非文章内容页(比如App内的列表页、活动页等)。

问题:统计每篇文章同一时刻最大在看人数,如果同一时刻有进入也有离开时,先记录用户数增加再记录减少,结果按最大人数降序。

输出示例

示例数据的输出结果如下:

artical_idmax_uv
90013
90022

解释:10点0分10秒时,有3个用户正在浏览文章9001;11点01分0秒时,有2个用户正在浏览文章9002。

SQL Schema

sql
DROP TABLE IF EXISTS tb_user_log;
CREATE TABLE tb_user_log
(
    id         INT PRIMARY KEY AUTO_INCREMENT COMMENT '自增ID',
    uid        INT NOT NULL COMMENT '用户ID',
    artical_id INT NOT NULL COMMENT '视频ID',
    in_time    datetime COMMENT '进入时间',
    out_time   datetime COMMENT '离开时间',
    sign_in    TINYINT DEFAULT 0 COMMENT '是否签到'
) CHARACTER SET utf8
  COLLATE utf8_bin;

INSERT INTO tb_user_log(uid, artical_id, in_time, out_time, sign_in)
VALUES (101, 9001, '2021-11-01 10:00:00', '2021-11-01 10:00:11', 0),
       (102, 9001, '2021-11-01 10:00:09', '2021-11-01 10:00:38', 0),
       (103, 9001, '2021-11-01 10:00:28', '2021-11-01 10:00:58', 0),
       (104, 9002, '2021-11-01 11:00:45', '2021-11-01 11:01:11', 0),
       (105, 9001, '2021-11-01 10:00:51', '2021-11-01 10:00:59', 0),
       (106, 9002, '2021-11-01 11:00:55', '2021-11-01 11:01:24', 0),
       (107, 9001, '2021-11-01 10:00:01', '2021-11-01 10:01:50', 0);

答案

sql
SELECT artical_id, MAX(uv_cnt) AS `max_uv`
FROM (SELECT artical_id, SUM(uv) OVER (PARTITION BY artical_id ORDER BY time, uv DESC ) AS `uv_cnt`
      FROM (SELECT artical_id, in_time AS `time`, 1 AS `uv`
            FROM tb_user_log
            WHERE artical_id <> 0
            UNION ALL
            SELECT artical_id, out_time AS `time`, -1 AS `uv`
            FROM tb_user_log
            WHERE artical_id <> 0) a) b
GROUP BY artical_id
ORDER BY max_uv DESC;