on 2020 May 11 6:36 AM
I have a field with Pos in a table. Now I want to create a group value that I will use later in a new column with sql like this: I've tested functions for last_value and first_value, but I couldn't solve it.
Pos GroupValue --- ---------- 30 1 30 1 100 0 100 0 100 0 110 1 110 1 110 1 120 0 120 0 130 1 130 1 130 1 130 1 140 0 140 0 150 1 150 1
Request clarification before answering.
A nice use case for OLAP, methinks:
create table TestPos( -- add a PK column just to show how to conserve original order PK int default autoincrement primary key, Pos int not null ); -- Sample date insert TestPos(Pos) values (30), (30), (100), (100), (100), (110), (110), (110), (120), (120), (130), (130), (130), (130), (140), (140), (150), (150); -- Use the DENSE_RANK window function to "number" the groups with identical values -- and apply MOD 2 to the result select Pos, mod(PosRank, 2) as GroupValue from (select PK, Pos, dense_rank() over (order by Pos) as PosRank from TestPos order by 1) DT order by PK, Pos; -- You can also directly apply MOD to the window function select Pos, mod(dense_rank() over (order by Pos), 2) as GroupValue from TestPos order by Pos;
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.
User | Count |
---|---|
80 | |
30 | |
10 | |
8 | |
8 | |
7 | |
6 | |
6 | |
4 | |
4 |
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.