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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
SharonCNE
Frequent Visitor

Inventory at multiple locations and multiple dates

Hi everyone.  I have a list of inventory from multiple locations that was taken on different dates.  I need to know the current total inventory for each item using the last date posted from each location.  Here is an example of my data

 

DateLocationItemQuantity
3/31/2020Location AItem 40
3/31/2020Location AItem 1156
3/31/2020Location AItem 20
3/31/2020Location AItem 30
4/10/2020Location AItem 40
4/10/2020Location AItem 10
4/10/2020Location AItem 2723
4/10/2020Location AItem 3377
4/14/2020Location BItem 492
4/14/2020Location CItem 459
4/14/2020Location EItem 412
4/14/2020Location BItem 11
4/14/2020Location CItem 10
4/14/2020Location EItem 16
4/14/2020Location BItem 219
4/14/2020Location CItem 214
4/14/2020Location EItem 26
4/14/2020Location BItem 33
4/14/2020Location CItem 37
4/14/2020Location EItem 312
4/15/2020Location EItem 46
4/15/2020Location DItem 41
4/15/2020Location FItem 443
4/15/2020Location GItem 416
4/15/2020Location EItem 10
4/15/2020Location DItem 10
4/15/2020Location FItem 10
4/15/2020Location GItem 11
4/15/2020Location EItem 26
4/15/2020Location DItem 223
4/15/2020Location FItem 212
4/15/2020Location GItem 251
4/15/2020Location EItem 36
4/15/2020Location DItem 30
4/15/2020Location FItem 3110
4/15/2020Location GItem 310
4/16/2020Location AItem 40
4/16/2020Location AItem 1452
4/16/2020Location AItem 2611
4/16/2020Location AItem 31525
4/17/2020Location AItem 40
4/17/2020Location AItem 1452
4/17/2020Location AItem 2481
4/17/2020Location AItem 31475
9 REPLIES 9
camargos88
Community Champion
Community Champion

Hi @SharonCNE ,

 

Try those measures:

 

_LastDate = CALCULATE(MAX('Table'[Date]); ALLEXCEPT('Table';'Table'[Item]))
 
Measure = CALCULATE(SUM('Table'[Quantity]); FILTER(ALLEXCEPT('Table'; 'Table'[Item]); 'Table'[Date] = [_LastDate]))
 
Capture.PNG
 
Did I answer your question? Mark my post as a solution!
Ricardo


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

Proud to be a Super User!



Ricardo thanks for answering so quickly - im getting this error

 

The function SUM cannot work with values of type String

@SharonCNE ,

 

Be sure the quantity column is numeric.

 

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



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

Proud to be a Super User!



Ricardo - yes value is a whole number :). the item is Text but I can't change that

Ricardo - I was just looking at your result table and It's actually the result I'm looking for:

 

If you look at the data provided

 

Item 3 has 10 entries

 

3/31/20 location A 0

4/10/20 location A 377

4/14/20 location B 3

4/14/20 location C 7

4/14/20 location E 12

4/15/20 location F 110

4/15/20 location G 10

4/16/20 location A 1525

4/17/20 location A 1475

 

the measure I am trying to create would look at that - determine the latest date for EACH location and SUM all those together - in this example it would be the amounts shown for B + C + E + F + G and ONLY the amount for A on 4/17/20 (because it was the latest date it was reported at that location)

 

and so on and so forth.  Does that make sense?

Hi @SharonCNE ,

 

Try this measure:

 

Measure =
SUMX(
ADDCOLUMNS(
SUMMARIZE('Table';
'Table'[Item];
'Table'[Location];
"Max"; MAX('Table'[Date]));
"Value"; CALCULATE(SUM('Table'[Quantity]); FILTER('Table'; 'Table'[Item] = EARLIER('Table'[Item]) && 'Table'[Location] = EARLIER('Table'[Location]) && 'Table'[Date] = [Max])));
[Value]
)
 
Capture.PNG
 
Did I answer your question? Mark my post as a solution!
Ricardo


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

Proud to be a Super User!



Ricardo - that was it!! thank you. Much more complicated than I could have figured out 🙂

@SharonCNE ,

 

Nice!

 

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



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

Proud to be a Super User!



@SharonCNE ,

 

Can you share your pbix ?

 

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



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

Proud to be a Super User!



Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors