Share feedback directly with Fabric product managers, participate in targeted research studies and influence the Fabric roadmap.
Sign up nowGet Fabric certified for FREE! Don't miss your chance! Learn more
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.
Thank you all in advance.
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:
Pete
Proud to be a Datanaut!
Share feedback directly with Fabric product managers, participate in targeted research studies and influence the Fabric roadmap.
| User | Count |
|---|---|
| 7 | |
| 4 | |
| 4 | |
| 4 | |
| 3 |
| User | Count |
|---|---|
| 12 | |
| 11 | |
| 11 | |
| 7 | |
| 6 |