The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredCompete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.
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 date | our_item_number | available | store |
4/10/24 10:00 AM | 123 | 800 | 5 |
4/10/24 11:00 AM | 123 | 2250 | 5 |
4/10/24 12:00 PM | 123 | 8750 | 5 |
4/10/24 10:00 AM | 223 | 500 | 5 |
4/10/24 11:00 AM | 223 | 1000 | 5 |
4/10/24 12:00 PM | 223 | 1500 | 5 |
4/10/24 11:00 AM | 223 | -2100 | 7 |
4/10/24 1:00 PM | 223 | -1050 | 7 |
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:
store | our_item_number | OH QTY |
5 | 123 | 8750 |
5 | 123 | 1500 |
7 | 223 | -1050 |
TOTAL | -1050 |
output that I want:
store | our_item_number | OH QTY |
5 | 123 | 8750 |
5 | 123 | 1500 |
7 | 223 | -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!
Solved! Go to Solution.
please try
OH QTY =
SUMX (
SUMMARIZE ( Inventory, Inventory[store], Inventory[our_item_numver] ),
SUMX (
TOPN ( 1, CALCULATETABLE ( Inventory ), Inventory[File Date] ),
Inventory[Available]
)
)
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.
User | Count |
---|---|
26 | |
10 | |
8 | |
6 | |
6 |
User | Count |
---|---|
32 | |
14 | |
10 | |
10 | |
9 |