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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
GMadd
Helper I
Helper I

Distinct Net Value From Deliveries

 

I am pulling a report from my ERP that lists deliveries shipped at the item level but populates the total net value shipped for delivery on each item line (repeating the total net value for the delivery on each item line). I cannot remove the duplicate deliveries from my data since I am using the item level info on other reports.

I want the net value for each delivery shipped on my report.  Basicaly I want a formula that removes the duplicate delivery numbers and gives me the net value. I wrote a formula that I thought would work but it did not.

Net Val = SUMX(DISTINCT('Delivery Tracking'[Delivery]),MAX('Delivery Tracking'[Net Value]))
Below is my table. The total for the Net Value should be $22,754.72

DeliveryPlantAct. Gds Mvmnt DateMaterialNet Value
88033289D7963/13/202422852BIO13,828.17
88033289D7963/13/202422851BIO13,828.17
88033289D7963/13/202426744BIO13,828.17
88033289D7963/13/202426743BIO13,828.17
88033289D7963/13/202426344BIO13,828.17
88033289D7963/13/202424285BIO13,828.17
88033289D7963/13/202442614BIO13,828.17
88033289D7963/13/202442624BIO13,828.17
88033289D7963/13/202442634BIO13,828.17
88033289D7963/13/202442638BIO13,828.17
88033289D7963/13/202442630BIO13,828.17
88033289D7963/13/202442650BIO13,828.17
88034684D7963/13/202442630BIO8,926.55
88034684D7963/13/202442656BIO8,926.55
88034684D7963/13/202425766BIO8,926.55
88034684D7963/13/202452368BIO8,926.55
88034684D7963/13/202425767BIO8,926.55
88034684D7963/13/202452366BIO8,926.55
88034684D7963/13/202425768BIO8,926.55
88034684D7963/13/202452728BIO8,926.55
Thank you for your help
 
2 ACCEPTED SOLUTIONS

Net Val = SUMX(FILTER(SUMMARIZE('Delivery Tracking',[Delivery],[Act. Gds Mvmnt Date],[Net Value]),FORMAT([Act. Gds Mvmnt Date],"yyyymm")=FORMAT(TODAY(),"yyyymm")),[Net Value])

lbendlin_0-1710799965572.png

 

View solution in original post

FORMAT([Act. Gds Mvmnt Date],"yyyymm")=FORMAT(TODAY(),"yyyymm")

We are comparing the YearMonth of your data against the YearMonth of the "current"  month, ie today's month.

View solution in original post

11 REPLIES 11
GMadd
Helper I
Helper I

I want to use the same measure you created but I want to limit the total to just the current month. My data table has two years worth of shipping data and currently the measure is giving me the total for all deliveries in my table. I do not want to use a filter on my visual for this. 

Sample table below. Since the current month year is March 2024 the total should be $355,470.06 Ignoring any other months.

DeliveryPlantAct. Gds Mvmnt DateMaterialNet Value
88028342D7962/28/202421001STM$44,497.76
88029678D7962/28/202450024ACL$16,874.60
88029678D7962/28/202410020ACL$16,874.60
88031087D7962/29/202443128CLX$374.48
88031087D7962/29/202442432CLX$374.48
88031087D7962/29/202444240CLX$374.48
88031086D7962/29/202432636CLX$381.11
88031086D7962/29/202424205CLX$381.11
88031085D7962/29/202436020CLX$483.40
88031077D7962/29/202442432CLX$278.62
88031077D7962/29/202436020CLX$278.62
88031077D7962/29/202424205CLX$278.62
88027366D7963/1/202475030CSP$33,398.76
88027366D7963/1/202423002CSP$33,398.76
88027366D7963/1/202436006CLX$33,398.76
88028943D7963/1/202426342BIO$131,246.24
88028943D7963/1/202423733BIO$131,246.24
88028943D7963/1/202423762BIO$131,246.24
88028943D7963/1/202426344BIO$131,246.24
88027157D7963/1/202423758BIO$57,174.68
88027157D7963/1/202423756BIO$57,174.68
88031155D7963/4/202417465STM$127,135.78
88031143D7963/4/202418030STM$6,514.60

Thank you for your quick response. This worked perfectly.

Net Val = SUMX(FILTER(SUMMARIZE('Delivery Tracking',[Delivery],[Act. Gds Mvmnt Date],[Net Value]),FORMAT([Act. Gds Mvmnt Date],"yyyymm")=FORMAT(TODAY(),"yyyymm")),[Net Value])

lbendlin_0-1710799965572.png

 

this is working but can you explain how it is only selecting the current month year? I would like to get a better understanding.

 

Thanks again

FORMAT([Act. Gds Mvmnt Date],"yyyymm")=FORMAT(TODAY(),"yyyymm")

We are comparing the YearMonth of your data against the YearMonth of the "current"  month, ie today's month.

Ok one more question. I thought I could figure it out but just can't. Just as I asked for the net value I need a total count of deliveries shipped for current month. Data is below and it should show four deliveries shipped in March (current month). 

DeliveryAct. Gds Mvmnt Date
880290822/29/2024
880290672/29/2024
880290652/29/2024
880290512/29/2024
880290082/29/2024
880289832/29/2024
880289822/29/2024
880289802/29/2024
880289752/29/2024
880289552/29/2024
880278832/29/2024
880303392/29/2024
880247333/1/2024
880305313/4/2024
880305313/4/2024
880305313/4/2024
880318273/4/2024
880318273/4/2024
880318273/4/2024
880318273/4/2024
880318273/4/2024
880318273/4/2024
880317423/4/2024
880317423/4/2024
880317423/4/2024
880317423/4/2024
880317423/4/2024

You can use the implicit "Count (Distinct)"  in the visual  for that, or implement the same in the formula explicitly.

Right I am using this below to get the distinct count of deliveries but can't seem to restrict it to the current month.

Count of Deliveries Shipped = DISTINCTCOUNT('Delivery Tracking'[Delivery])
GMadd
Helper I
Helper I

Thanks that worked perfectly. Now I need to show only the current months net value. How to I add that to the measure you wrote above?

 

Thanks again!!

Please provide sample data that fully covers your issue.
Please show the expected outcome based on the sample data you provided.

lbendlin
Super User
Super User

you were close

 

 

Net Val = SUMX(SUMMARIZE('Delivery Tracking',[Delivery],[Net Value]),[Net Value])

 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.