有两个表,朋友关系表user_friend,用户步数表user_steps。朋友关系表包含两个字段,用户id,用户好友的id;用户步数表包含两个字段,用户id,用户的步数.用户在好友中的排名
-- user_friend 数据
+----------+------------+
| user_id | friend_id |
+----------+------------+
| 1 | 2 |
| 1 | 3 |
| 2 | 1 |
| 2 | 3 |
| 2 | 4 |
| 2 | 5 |
| 3 | 1 |
| 3 | 4 |
| 3 | 5 |
| 4 | 2 |
| 4 | 3 |
| 4 | 5 |
| 5 | 2 |
| 5 | 3 |
| 5 | 4 |
+----------+------------+
--user_friend数据
+---------------------+-------------------+
| user_steps.user_id | user_steps.steps |
+---------------------+-------------------+
| 1 | 100 |
| 2 | 95 |
| 3 | 90 |
| 4 | 80 |
| 5 | 10 |
+---------------------+-------------------+
维度 | 评分 |
---|---|
题目难度 | ⭐️⭐️⭐️ |
题目清晰度 | ⭐️⭐️⭐️⭐️⭐️ |
业务常见度 | ⭐️⭐️⭐️⭐️ |
解法分析
执行SQL
--好友步数
select t1.user_id, t1.friend_id, t2.steps
from user_friend t1
join user_steps t2
on t1.friend_id = t2.user_id
union all
-- 自己步数
select user_id, user_id as friend_id, steps
from user_steps
查询结果
+--------------+----------------+------------+
| _u1.user_id | _u1.friend_id | _u1.steps |
+--------------+----------------+------------+
| 1 | 2 | 95 |
| 1 | 3 | 90 |
| 2 | 1 | 100 |
| 2 | 3 | 90 |
| 2 | 4 | 80 |
| 2 | 5 | 10 |
| 3 | 1 | 100 |
| 3 | 4 | 80 |
| 3 | 5 | 10 |
| 4 | 2 | 95 |
| 4 | 3 | 90 |
| 4 | 5 | 10 |
| 5 | 2 | 95 |
| 5 | 3 | 90 |
| 5 | 4 | 80 |
| 1 | 1 | 100 |
| 2 | 2 | 95 |
| 3 | 3 | 90 |
| 4 | 4 | 80 |
| 5 | 5 | 10 |
+--------------+----------------+------------+
查询SQL
select tt1.user_id,
tt1.friend_id,
tt1.steps,
row_number() over (partition by tt1.user_id order by tt1.steps desc) as row_num
from (
--好友步数
select t1.user_id,
t1.friend_id,
t2.steps
from user_friend t1
join user_steps t2
on t1.friend_id = t2.user_id
union all
-- 自己步数
select user_id,
user_id as friend_id,
steps
from user_steps) tt1
执行结果
+--------------+----------------+------------+----------+
| tt1.user_id | tt1.friend_id | tt1.steps | row_num |
+--------------+----------------+------------+----------+
| 1 | 1 | 100 | 1 |
| 1 | 2 | 95 | 2 |
| 1 | 3 | 90 | 3 |
| 2 | 1 | 100 | 1 |
| 2 | 2 | 95 | 2 |
| 2 | 3 | 90 | 3 |
| 2 | 4 | 80 | 4 |
| 2 | 5 | 10 | 5 |
| 3 | 1 | 100 | 1 |
| 3 | 3 | 90 | 2 |
| 3 | 4 | 80 | 3 |
| 3 | 5 | 10 | 4 |
| 4 | 2 | 95 | 1 |
| 4 | 3 | 90 | 2 |
| 4 | 4 | 80 | 3 |
| 4 | 5 | 10 | 4 |
| 5 | 2 | 95 | 1 |
| 5 | 3 | 90 | 2 |
| 5 | 4 | 80 | 3 |
| 5 | 5 | 10 | 4 |
+--------------+----------------+------------+----------+
查询SQL
select user_id,
row_num
from (select tt1.user_id,
tt1.friend_id,
tt1.steps,
row_number() over (partition by tt1.user_id order by tt1.steps desc) as row_num
from (
--好友步数
select t1.user_id,
t1.friend_id,
t2.steps
from user_friend t1
join user_steps t2
on t1.friend_id = t2.user_id
union all
-- 自己步数
select user_id,
user_id as friend_id,
steps
from user_steps) tt1) tt2
where user_id = friend_id
执行结果
+----------+----------+
| user_id | row_num |
+----------+----------+
| 1 | 1 |
| 2 | 2 |
| 3 | 2 |
| 4 | 3 |
| 5 | 4 |
+----------+----------+
CREATE TABLE user_friend
(
user_id INT,
friend_id INT
) ROW FORMAT DELIMITED FIELDS TERMINATED BY '\t';
-- 插入数据
INSERT INTO user_friend
VALUES (1, 2),
(1, 3),
(2, 1),
(2, 3),
(2, 4),
(2, 5),
(3, 1),
(3, 4),
(3, 5),
(4, 2),
(4, 3),
(4, 5),
(5, 2),
(5, 3),
(5, 4);
CREATE TABLE user_steps
(
user_id INT,
steps INT
) ROW FORMAT DELIMITED FIELDS TERMINATED BY '\t';
INSERT INTO user_steps
VALUES (1, 100),
(2, 95),
(3, 90),
(4, 80),
(5, 10);
扫码关注腾讯云开发者
领取腾讯云代金券
Copyright © 2013 - 2025 Tencent Cloud. All Rights Reserved. 腾讯云 版权所有
深圳市腾讯计算机系统有限公司 ICP备案/许可证号:粤B2-20090059 深公网安备号 44030502008569
腾讯云计算(北京)有限责任公司 京ICP证150476号 | 京ICP备11018762号 | 京公网安备号11010802020287
Copyright © 2013 - 2025 Tencent Cloud.
All Rights Reserved. 腾讯云 版权所有