Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Get Fabric certified for FREE! Don't miss your chance! Learn more

Reply
Anonymous
Not applicable

Group rows with different by 1 (Power Query)

Hi

 

I have a table where columne "link" is different by 1 from another (but it is one event for subject)
and I need a "subject" group
if link to one row > more than 1 link to another row (and maybe only 1 row in group)

subjectlinkeventdatedate 2
07-00112Visit04.05.2023 
07-00113Visit 05.06.2023
07-00123Visit14.05.2023 
07-00245Visit15.06.2023 
07-00246Visit 17.06.2023
07-00278Visit23.05.2023 
07-00279Visit 25.05.2023
07-00341Visit01.04.2023 

 

 

subjectlinkeventdatedate 2index
07-00112Visit04.05.2023 1
07-00113Visit 05.06.20232
07-00123Visit14.05.2023 1
07-00245Visit15.06.2023 1
07-00246Visit 17.06.20232
07-00278Visit23.05.2023 1
07-00279Visit 25.05.20232
07-00341Visit01.04.2023 1


5 groups as result

 Group Columne with Table
subjectlinkeventdatedate 2index
07-00112Visit04.05.2023 1
 13Visit 05.06.20232
07-00123Visit14.05.2023 1
07-00245Visit15.06.2023 1
 46Visit 17.06.20232
07-00278Visit23.05.2023 1
 79Visit 25.05.20232
07-00341Visit01.04.2023 1



1 ACCEPTED SOLUTION
dufoq3
Super User
Super User

Hi @Anonymous, another solution:

 

Result

dufoq3_0-1721203023890.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ddDBCcAgDAXQVcSzlSQabRfpRRzAc7s/VQqaWrxEAs//ISlpiBsAaqOR6jjLVe76grfAloBcXZTORkInoGqYLYQXfyBJiIvE1upZwpH2h2GqxvivbjDuApJbV8djSiTuuMP2z6M8D9p6oZGYHw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [subject = _t, link = _t, event = _t, date = _t, #"date 2" = _t]),
    ChangedType = Table.TransformColumnTypes(Source,{{"link", Int64.Type}, {"date", type date}, {"date 2", type date}}, "sk-SK"),
    GroupedRowsLocal = Table.Group(ChangedType, {"subject", "link"}, {{"All", each Table.AddIndexColumn(_, "Index", 1, 1, Int64.Type), type table}}, GroupKind.Local,
        (x,y)=> Number.From( x[subject] <> y[subject] or y[link] - x[link] > 1 ) ),
    CombinedAll = Table.Combine(GroupedRowsLocal[All])
in
    CombinedAll

Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

View solution in original post

2 REPLIES 2
dufoq3
Super User
Super User

Hi @Anonymous, another solution:

 

Result

dufoq3_0-1721203023890.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ddDBCcAgDAXQVcSzlSQabRfpRRzAc7s/VQqaWrxEAs//ISlpiBsAaqOR6jjLVe76grfAloBcXZTORkInoGqYLYQXfyBJiIvE1upZwpH2h2GqxvivbjDuApJbV8djSiTuuMP2z6M8D9p6oZGYHw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [subject = _t, link = _t, event = _t, date = _t, #"date 2" = _t]),
    ChangedType = Table.TransformColumnTypes(Source,{{"link", Int64.Type}, {"date", type date}, {"date 2", type date}}, "sk-SK"),
    GroupedRowsLocal = Table.Group(ChangedType, {"subject", "link"}, {{"All", each Table.AddIndexColumn(_, "Index", 1, 1, Int64.Type), type table}}, GroupKind.Local,
        (x,y)=> Number.From( x[subject] <> y[subject] or y[link] - x[link] > 1 ) ),
    CombinedAll = Table.Combine(GroupedRowsLocal[All])
in
    CombinedAll

Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

AlienSx
Super User
Super User

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    sort = Table.Sort(Source,{{"subject", Order.Ascending}, {"link", Order.Ascending}}),
    recs = List.Buffer(Table.ToRecords(sort)),
    gen = List.Generate(
        () => [i = 0, r = recs{0}, new_group = true, index = 1],
        (x) => x[i] < List.Count(recs),
        (x) => 
            [
                i = x[i] + 1, 
                r = recs{i}, 
                new_group = (r[link] - x[r][link]) <> 1 or r[subject] <> x[r][subject],
                index = if new_group then 1 else x[index] + 1
            ],
        (x) => 
            x[r] & 
            [subject = if x[new_group] then x[r][subject] else null] & 
            [index = x[index]]
    ),
    to_table = Table.FromRecords(gen)
in
    to_table

Helpful resources

Announcements
Sticker Challenge 2026 Carousel

Join our Community Sticker Challenge 2026

If you love stickers, then you will definitely want to check out our Community Sticker Challenge!

January Power BI Update Carousel

Power BI Monthly Update - January 2026

Check out the January 2026 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.