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
toum
Helper II
Helper II

Get distinct rows

Hello All,

Please I need your help on this, I have a table that contains a column named Ref and another column named status I need to get all the rows when status='On', then I should take all records when status=OFF and Ref are not taken from the beginning while taking the "On" status.

 

toum_0-1673438361800.png

Thank you all in advance.

1 REPLY 1
BA_Pete
Super User
Super User

Hi @toum ,

 

Try this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjNT0lHyd3MDko5KsTrRSuYIASewgKERXMAZImAKF3BBUuEHJFyRFID4bmC+EZzvDuGbw/geCPlwR88QTz93IMtbKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Ref = _t, Status = _t, Link = _t]),
    groupRef = Table.Group(Source, {"Ref"}, {{"Count", each Table.RowCount(_), Int64.Type}, {"data", each _, type table [Ref=nullable text, Status=nullable text, Link=nullable text]}}),
    expandData = Table.ExpandTableColumn(groupRef, "data", {"Status", "Link"}, {"Status", "Link"}),
    filterCriteria = Table.SelectRows(expandData, each ([Status] = "OFF" and [Count] = 1) or ([Status] = "ON"))
in
    filterCriteria

 

Summary:

1) groupRef = group on the [Ref] column and create one Count aggregate and one All Rows aggregate column.

2) expandData = expand the nested [data] column back out to reinstate original columns.

3) filterCriteria = filter table using [Count] column as part of the criteria.

 

Example output:

BA_Pete_0-1673443989167.png

 

Pete



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




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!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

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.

Top Solution Authors