脚踏实地、勇往直前!
全部博文(1005)
分类: Mysql/postgreSQL
2018-06-11 20:16:29
mysql> SELECT tb_rank_score.*,@r :=@r + 1 AS rank -> FROM tb_rank_score,(SELECT @r := 0) r -> ORDER BY score desc; +------+-------+------+ | city | score | rank | +------+-------+------+ | sh | 90 | 1 | | sz | 89 | 2 | | sz | 89 | 3 | | sz | 78 | 4 | | sh | 78 | 5 | | sz | 76 | 6 | | sh | 76 | 7 | | sh | 67 | 8 | | sz | 50 | 9 | | sh | 34 | 10 | +------+-------+------+ 10 rows in set (0.00 sec) |
mysql> SELECT tb_rank_score.* , -> CASE -> WHEN @p=score THEN @r -> WHEN @p:=score THEN @r:=@r+1 -> END rank -> FROM tb_rank_score,(SELECT @r:=0,@p:=NULL)r -> ORDER BY score desc; +------+-------+------+ | city | score | rank | +------+-------+------+ | sh | 90 | 1 | | sz | 89 | 2 | | sz | 89 | 2 | | sz | 78 | 3 | | sh | 78 | 3 | | sz | 76 | 4 | | sh | 76 | 4 | | sh | 67 | 5 | | sz | 50 | 6 | | sh | 34 | 7 | +------+-------+------+ 10 rows in set (0.00 sec) |
mysql> SELECT city,score,rank -> FROM -> ( -> SELECT tb_rank_score.*,IF(@p=city,@r:=@r+1,@r:=1) AS rank, -> @p:=city -> FROM tb_rank_score,(SELECT @p:=NULL,@r:=0)r -> ORDER BY city,score desc -> )s; +------+-------+------+ | city | score | rank | +------+-------+------+ | sh | 90 | 1 | | sh | 78 | 2 | | sh | 76 | 3 | | sh | 67 | 4 | | sh | 34 | 5 | | sz | 89 | 1 | | sz | 89 | 2 | | sz | 78 | 3 | | sz | 76 | 4 | | sz | 50 | 5 | +------+-------+------+ 10 rows in set (0.00 sec) |
mysql> SELECT city,score,rank -> FROM -> ( -> SELECT *, -> IF(@p=city, -> CASE -> WHEN @s=score THEN @r -> WHEN @s:=score THEN @r:=@r+1 -> END, -> @r:=1 ) AS rank, -> @p:=city, -> @s:=score -> FROM tb_rank_score,(SELECT @p:=NULL,@s:=NULL,@r:=0)r -> ORDER BY city,score desc -> )s; +------+-------+------+ | city | score | rank | +------+-------+------+ | sh | 90 | 1 | | sh | 78 | 2 | | sh | 76 | 3 | | sh | 67 | 4 | | sh | 34 | 5 | | sz | 89 | 1 | | sz | 89 | 1 | | sz | 78 | 2 | | sz | 76 | 3 | | sz | 50 | 4 | +------+-------+------+ 10 rows in set (0.00 sec) |
mysql> SELECT city,score,rank -> FROM -> ( -> SELECT *, -> IF(@p=city, -> CASE -> WHEN @s=score THEN @r -> WHEN @s:=score THEN @r:=@r+1 -> END, -> @r:=1 ) AS rank, -> @p:=city, -> @s:=score -> FROM tb_rank_score,(SELECT @p:=NULL,@s:=NULL,@r:=0)r -> ORDER BY city,score DESC -> )s -> WHERE rank <4; +------+-------+------+ | city | score | rank | +------+-------+------+ | sh | 90 | 1 | | sh | 78 | 2 | | sh | 76 | 3 | | sz | 89 | 1 | | sz | 89 | 1 | | sz | 78 | 2 | | sz | 76 | 3 | +------+-------+------+ 7 rows in set (0.00 sec) |