add batch remove batch split batch comment selection show hidden batches hide batch highlight batch
db<>fiddle
donate feedback about
By using db<>fiddle, you agree to license everything you submit by Creative Commons CC0.
create table CampaignPoints
(
UserId int,
CampaignId int,
CountryId int,
Points int
);

insert into CampaignPoints (UserId, CampaignId, CountryId, Points) values
(10, 1, 101, 72),
( 3, 1, 101, 30),
( 6, 1, 101, 72),
( 4, 1, 101, 49),
( 1, 1, 101, 53),
( 8, 1, 101, 67),
( 5, 1, 101, 6),
( 7, 1, 101, 87),
( 2, 1, 101, 41),
(11, 1, 101, 76),
( 9, 1, 101, 50);

select * from CampaignPoints;

UserId CampaignId CountryId Points
10 1 101 72
3 1 101 30
6 1 101 72
4 1 101 49
1 1 101 53
8 1 101 67
5 1 101 6
7 1 101 87
2 1 101 41
11 1 101 76
9 1 101 50
declare @userId int = 8;
declare @before int = 2;
declare @after int = 2;

with cte_rank as
(
select cp.UserId,
cp.CampaignId,
cp.CountryId,
cp.Points,
rank() over(order by cp.Points desc) as RowRank
from CampaignPoints cp
)
select cr2.*
from cte_rank cr
join cte_rank cr2
on cr2.RowRank >= cr.RowRank - @before
and cr2.RowRank <= cr.RowRank + @after
where cr.UserId = @userId
order by cr2.RowRank;

UserId CampaignId CountryId Points RowRank
10 1 101 72 3
6 1 101 72 3
8 1 101 67 5
1 1 101 53 6
9 1 101 50 7