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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
kaym
Helper I
Helper I

remove Max values in an index column

How can i remove the row with highest order count in each shipment? For below data:

kaym_0-1707939082499.png

for example, for shipment # 37136 it should not show the row with order count 4

1 ACCEPTED SOLUTION
watkinnc
Super User
Super User

Let's say your last step was PriorStep. I would group by Shipment # column, and choose the Max Aggregation for the ORDER COUNT column. Name that step "Group" or whatever you want. Then you can join that table to PriorStep using a left anti join. So after grouping, 

 

= Table.Join(PriorStep, {"SHIPMENT #", "ORDER COUNT"}, Group, {"GROUPED SHIPMENT # COLUMN", "Max ORDER COUNT"}, JoinKind.LeftAnti)

 

Side note: using the "#" character in your column name is going to get you into trouble some day, because somehow it'll get parsed as an escape character and mess up your quotes.

 

--Nate


I’m usually answering from my phone, which means the results are visualized only in my mind. You’ll need to use my answer to know that it works—but it will work!!

View solution in original post

5 REPLIES 5
mussaenda
Super User
Super User

What if the Shipment # has no duplicate?

watkinnc
Super User
Super User

Let's say your last step was PriorStep. I would group by Shipment # column, and choose the Max Aggregation for the ORDER COUNT column. Name that step "Group" or whatever you want. Then you can join that table to PriorStep using a left anti join. So after grouping, 

 

= Table.Join(PriorStep, {"SHIPMENT #", "ORDER COUNT"}, Group, {"GROUPED SHIPMENT # COLUMN", "Max ORDER COUNT"}, JoinKind.LeftAnti)

 

Side note: using the "#" character in your column name is going to get you into trouble some day, because somehow it'll get parsed as an escape character and mess up your quotes.

 

--Nate


I’m usually answering from my phone, which means the results are visualized only in my mind. You’ll need to use my answer to know that it works—but it will work!!
smpa01
Super User
Super User

@kaym

Table.SelectRows(prevStep, (x)=>x[orderCount]<>List.Max(Table.SelectRows(prevStep, (y)=> x[shipment]=y[shipment])[orderCount]))
Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

This didn't work : (

 @smpa01 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSAeJYHQjLCM4yBrOMgCxLOMvQQCk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [shipment = _t, orderCount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"shipment", Int64.Type}, {"orderCount", Int64.Type}}),
    #"Filtered Rows" = Table.SelectRows(#"Changed Type", (x)=>x[orderCount]<>List.Max(Table.SelectRows(#"Changed Type", (y)=> x[shipment]=y[shipment])[orderCount]))
in
    #"Filtered Rows"

 

@kaym try the above

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel1

Power BI Monthly Update - May 2024

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

Top Solution Authors
Top Kudoed Authors