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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Rule83
New Member

Unique and consecutive values count and list to one string

Here is the thing. Maybe due to of all the (probable) possibilities I can't figure out exactly how to do the following. My preference is to do it via the query editor (M). This to I can (re)use and maybe modify it for other projects:

 

 

Table is called 'Data'

 


Names     Value
NameB     X
NameB     X
NameA     Y
NameB     Y
NameC     X
NameC     X

 

 

Desired operations/functions:
1. Look for all unique Names and count them consecutively and list them in CountCONS
2. Look for alle unique Names and count the total of occurences and list them in CountALL
3. Add (in consecutive order) CURRENT&ALLPREVIOUS  Values into one string and list them in ValuesCONS behind every row
4. Add (in consecutive order) ALL the Values into one string and list them in ValuesALL behind every row
5. Look for the values "X" AND "Y" in ValuesALL and if both are found at least 1 time (no matter the order) list "YES" in column Combination otherwise "NO"

 


Desired output:
Names     Values     CountCONS     CountALL     ValuesCONS     ValuesALL     Combination
NameB     X          1             3            X              XXY           YES
NameB     X          2             3            XX             XXY           YES
NameA.    Y          1             1            Y              Y             NO
NameB.    Y          3             3            XXY            XXY           YES
NameC.    X          1             2            X              XX            NO
NameC.    X          2             2            XX             XX            NO

 


I've already used many googled variants with COUNT/COUNTX/FILTER/SUMMARISE/FILTER etc the last 2 days. but I got 'lost in translation'. Maybe a bit extensive, but maybe many others can be helped by this as well.

 


Hope you can help.

1 ACCEPTED SOLUTION
MarcelBeug
Community Champion
Community Champion

Sure:

 

let
    Source = Data,
    AddedOriginalSort = Table.AddIndexColumn(Source, "OriginalSort", 1, 1),
    Grouped = Table.Group(AddedOriginalSort, {"Names"}, {{"GroupedData", each _, type table}, {"CountALL", each Table.RowCount(_), type number}, {"ValuesALL", each Text.Combine([Value]), type text}}),
    AddedCountCONS = Table.TransformColumns(Grouped,{{"GroupedData", each Table.AddIndexColumn(_,"CountCONS",1,1)}}),
    ExpandedGroupedData = Table.ExpandTableColumn(AddedCountCONS, "GroupedData", {"Value", "OriginalSort", "CountCONS"}),
    OriginalSort = Table.Sort(ExpandedGroupedData,{{"OriginalSort", Order.Ascending}}),
    RemovedOroginalSort = Table.RemoveColumns(OriginalSort,{"OriginalSort"}),
    AddedValuesCONS = Table.AddColumn(RemovedOroginalSort, "ValuesCONS", each Text.Start([ValuesALL],[CountCONS])),
    AddedCombination = Table.AddColumn(AddedValuesCONS, "Combination", each if Text.Contains([ValuesALL],"X") and Text.Contains([ValuesALL],"Y") then "YES" else "NO"),
    ReorderedColumns = Table.ReorderColumns(AddedCombination,{"Names", "Value", "CountCONS", "CountALL", "ValuesCONS", "ValuesALL", "Combination"})
in
    ReorderedColumns
Specializing in Power Query Formula Language (M)

View solution in original post

2 REPLIES 2
MarcelBeug
Community Champion
Community Champion

Sure:

 

let
    Source = Data,
    AddedOriginalSort = Table.AddIndexColumn(Source, "OriginalSort", 1, 1),
    Grouped = Table.Group(AddedOriginalSort, {"Names"}, {{"GroupedData", each _, type table}, {"CountALL", each Table.RowCount(_), type number}, {"ValuesALL", each Text.Combine([Value]), type text}}),
    AddedCountCONS = Table.TransformColumns(Grouped,{{"GroupedData", each Table.AddIndexColumn(_,"CountCONS",1,1)}}),
    ExpandedGroupedData = Table.ExpandTableColumn(AddedCountCONS, "GroupedData", {"Value", "OriginalSort", "CountCONS"}),
    OriginalSort = Table.Sort(ExpandedGroupedData,{{"OriginalSort", Order.Ascending}}),
    RemovedOroginalSort = Table.RemoveColumns(OriginalSort,{"OriginalSort"}),
    AddedValuesCONS = Table.AddColumn(RemovedOroginalSort, "ValuesCONS", each Text.Start([ValuesALL],[CountCONS])),
    AddedCombination = Table.AddColumn(AddedValuesCONS, "Combination", each if Text.Contains([ValuesALL],"X") and Text.Contains([ValuesALL],"Y") then "YES" else "NO"),
    ReorderedColumns = Table.ReorderColumns(AddedCombination,{"Names", "Value", "CountCONS", "CountALL", "ValuesCONS", "ValuesALL", "Combination"})
in
    ReorderedColumns
Specializing in Power Query Formula Language (M)

Superb! I'll figure out how you've build it up and test it.

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 2025 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.