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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
bradcuris
New Member

Filter on a group of records

Greetings,

 

I have records grouped by a parent ID. I want to only return the grouped items that do not have a Active = "Current" in the group of records.

 

In the example below, I do not want the top for records (which have a unique parent ID). I want the last three since there is no Active = "Current" (these have another unique parent ID)

 

thanks

 

 

 

bradcuris_0-1657836905620.png

 

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMgQCJR0lx4KCovyy1BSlWB2SxZxLi4pS80rAQkZAgK6MKLFYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Parent ID" = _t, Active = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Parent ID", Int64.Type}, {"Active", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Parent ID"}, {{"All", each _, type table [Parent ID=nullable number, Active=nullable text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each List.Contains([All][Active],"Current")),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Custom] = false)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Custom"}),
    #"Expanded All" = Table.ExpandTableColumn(#"Removed Columns", "All", {"Active"}, {"Active"})
in
    #"Expanded All"

View solution in original post

3 REPLIES 3
bradcuris
New Member

Thanks,

 

But that only gives 3 rows. I was looking to get back all the rows that match the criteria

Your problem statement says - "I want the last three since there is no Active = "Current" (these have another unique parent ID)"

Hence, you are getting only 3.

In your actual data set, when you apply my method, you will get all unque parent IDs matching the criterion.

You need to replace my Source with your Source and delete changed type. 

Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMgQCJR0lx4KCovyy1BSlWB2SxZxLi4pS80rAQkZAgK6MKLFYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Parent ID" = _t, Active = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Parent ID", Int64.Type}, {"Active", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Parent ID"}, {{"All", each _, type table [Parent ID=nullable number, Active=nullable text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each List.Contains([All][Active],"Current")),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Custom] = false)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Custom"}),
    #"Expanded All" = Table.ExpandTableColumn(#"Removed Columns", "All", {"Active"}, {"Active"})
in
    #"Expanded All"

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors
Top Kudoed Authors