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
Anonymous
Not applicable

DAX

Hi everyone,

I'm experiencing a problem with my data. I have the table 'Outbound' which has Delivery, Freight Costs, Sales and Date fields.
I want to manipulate the Freight Costs column according to Delivery Field.

What I have
Delivery Freight     Sales
S102           $30         $300
S102           $30          $400
S103           $50          $500

What I want
Delivery    Freight    Sales
S102         $0        $300
S102         $30       $400
S103         $50       $500

Please note that I don't want to sum duplicates for the delivery, I want to write one of the duplicate values in freight costs for that particular delivery and make the other one 0 to ensure that the total sum of the column is accurate. Thanks for your help in advance.

 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Anonymous ,

 

This is the Power Query forum. In the Power Query Editor, we use the M language instead of the DAX language. There is a difference between the two. You can check this blog for reference.

 

My solution is completed in Power Query Editor.

Sample data

vstephenmsft_0-1639642196118.png

 

1.Select both columns and group by.

vstephenmsft_1-1639642213740.png

 

2.Select All Rows and click ok.

vstephenmsft_2-1639642261597.png

You get this.

vstephenmsft_3-1639642291256.png

 

 

3.Add a custom column. 

Table.AddIndexColumn([Count],"Index",1)

vstephenmsft_4-1639642335132.png

vstephenmsft_5-1639642349291.png

 

4.Expand the Sales column and the Index column, remove the Count column.

vstephenmsft_7-1639642659853.png

 

5.Add a conditional column, set if [Index] = 1 then [Freight] else 0.

vstephenmsft_8-1639642724004.png

vstephenmsft_9-1639642762934.png

 

6.Remove the unneeded columns and rename the custom column. Finally get the result.

vstephenmsft_10-1639642801452.png

 

You can download the .pbix to check.

 

 

Best Regards,

Stephen Tao

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

 

View solution in original post

3 REPLIES 3
Anonymous
Not applicable

Hi @Anonymous ,

 

This is the Power Query forum. In the Power Query Editor, we use the M language instead of the DAX language. There is a difference between the two. You can check this blog for reference.

 

My solution is completed in Power Query Editor.

Sample data

vstephenmsft_0-1639642196118.png

 

1.Select both columns and group by.

vstephenmsft_1-1639642213740.png

 

2.Select All Rows and click ok.

vstephenmsft_2-1639642261597.png

You get this.

vstephenmsft_3-1639642291256.png

 

 

3.Add a custom column. 

Table.AddIndexColumn([Count],"Index",1)

vstephenmsft_4-1639642335132.png

vstephenmsft_5-1639642349291.png

 

4.Expand the Sales column and the Index column, remove the Count column.

vstephenmsft_7-1639642659853.png

 

5.Add a conditional column, set if [Index] = 1 then [Freight] else 0.

vstephenmsft_8-1639642724004.png

vstephenmsft_9-1639642762934.png

 

6.Remove the unneeded columns and rename the custom column. Finally get the result.

vstephenmsft_10-1639642801452.png

 

You can download the .pbix to check.

 

 

Best Regards,

Stephen Tao

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

 

wdx223_Daniel
Community Champion
Community Champion

NewStep=Table.FromRecords(List.Accumulate(Table.ToRecords(PreviousStepName),{},(x,y)=>if x={} then {{y},Record.AddField([],y[Delivery],0)} else {x{0}&{y&[Freight=Record.FieldOrDefault(x{1},y[Delivery],1)*y[Freight]]},x{1}&Record.AddField([],y[Delivery],0)}){0})

ValtteriN
Community Champion
Community Champion

Hi,

If you are only concerned about the sum of the rows you can use this as an alternate way of achieving your goal:
Example data:

ValtteriN_0-1639412728656.png


1st I created a duplicate query and grouped it:

ValtteriN_1-1639412790767.png


#"Grouped Rows" = Table.Group(#"Changed Type", {"Delivery"}, {{"Count", each Table.RowCount(_), Int64.Type}})

After this I merged this count to the original:

ValtteriN_2-1639412851830.png


Now Simply divide the original value with the count to get a row specific value:

ValtteriN_3-1639412907207.png

 

Full M:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCjY0MFLSUTI2ABMGSrE6qGImCDFjINfUAEwAxWIB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Delivery = _t, Value = _t, Sales = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Delivery", type text}, {"Value", Int64.Type}, {"Sales", Int64.Type}}),
#"Merged Queries" = Table.NestedJoin(#"Changed Type", {"Delivery"}, #"DeliveryPQ Grouped", {"Delivery"}, "DeliveryPQ Grouped", JoinKind.LeftOuter),
#"Expanded DeliveryPQ Grouped" = Table.ExpandTableColumn(#"Merged Queries", "DeliveryPQ Grouped", {"Count"}, {"Count"}),
#"Added Custom" = Table.AddColumn(#"Expanded DeliveryPQ Grouped", "NewValue", each [Value]/[Count]),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Value", "Count"})
in
#"Removed Columns"

Maybe you can solve your issue by using this method?





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




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.