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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
3rdAbnormalForm
New Member

Sum of quantity based on latest file date of each item

I have an inventory fact table with fields: file date, items, available quantity, and store number. The different stores will upload their inventory multiple times through the day but it could be at different time stamps. I'm looking to find the available quantity for each item and store for the most recent file date.

 

Here's a sample table:

 

file dateour_item_numberavailablestore
4/10/24 10:00 AM1238005
4/10/24 11:00 AM12322505
4/10/24 12:00 PM12387505
4/10/24 10:00 AM2235005
4/10/24 11:00 AM22310005
4/10/24 12:00 PM22315005
4/10/24 11:00 AM223-21007
4/10/24 1:00 PM223-10507

 

Here's the measure that I've been using:

 

 

OH QTY = 
var maxdate =
CALCULATE(
    MAX(Inventory[File Date])
    )

return 
CALCULATE(
    SUMX('Inventory','Inventory'[Available]),
    Inventory[File Date] = maxdate
)

 

 

This works for the item/store level but it does not total correctly. It gives me only the sum of the available qty for the max value of the file date.

 

example of actual output:

 

storeour_item_numberOH QTY
51238750
51231500
7223-1050
TOTAL -1050

 

output that I want:

storeour_item_numberOH QTY
51238750
51231500
7223-1050
TOTAL 9200

 

From what I've read, it may be something to do with row context but I can't quite figure it out.

 

Any thoughts/comments are appreciated!

1 ACCEPTED SOLUTION
tamerj1
Super User
Super User

Hi @3rdAbnormalForm 

please try

OH QTY =
SUMX (
SUMMARIZE ( Inventory, Inventory[store], Inventory[our_item_numver] ),
SUMX (
TOPN ( 1, CALCULATETABLE ( Inventory ), Inventory[File Date] ),
Inventory[Available]
)
)

View solution in original post

2 REPLIES 2
tamerj1
Super User
Super User

Hi @3rdAbnormalForm 

please try

OH QTY =
SUMX (
SUMMARIZE ( Inventory, Inventory[store], Inventory[our_item_numver] ),
SUMX (
TOPN ( 1, CALCULATETABLE ( Inventory ), Inventory[File Date] ),
Inventory[Available]
)
)

Thank you for the quick reply! This does work and I marked it as the solution.

 

 

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.

Power BI Carousel June 2024

Power BI Monthly Update - June 2024

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

PBI_Carousel_NL_June

Fabric Community Update - June 2024

Get the latest Fabric updates from Build 2024, key Skills Challenge voucher deadlines, top blogs, forum posts, and product ideas.

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

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