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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
toum
Helper I
Helper I

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
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors