The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi All,
I have a current on hand amount and monthly ins and outs. Here is some sample data:
Date | In | Out | Fin |
Aug | 6 | 4 | |
Sep | 3 | 5 | |
Oct | 4 | 5 | |
Nov | 5 | 2 | |
Dec | 4 | 3 |
Assuming an on hand at the end of september of 10 then I would like a measure that will calculate forward and backwards like so:
Date | In | Out | Fin |
Aug | 6 | 4 | 12 |
Sep | 3 | 5 | 10 |
Oct | 4 | 5 | 9 |
Nov | 5 | 2 | 12 |
Dec | 4 | 3 | 13 |
Thanks!
Solved! Go to Solution.
Hi @STS_Joshua ,
Please try to create a measure as below:
Fin =
IF (
MAX ( 'Date'[Date] ) = DATE ( 2019, 8, 1 ), //Start date: 2019/08/01
12, //Initial Fin: 12
12
+ CALCULATE (
SUM ( 'Inputs'[Ins] ),
FILTER (
'Inputs',
'Inputs'[Date] <= MAX ( 'Date'[Date] )
&& 'Inputs'[Date] > DATE ( 2019, 8, 1 )
)
)
- CALCULATE (
SUM ( 'Outputs'[Outs] ),
FILTER (
'Outputs',
'Outputs'[Date] <= MAX ( 'Date'[Date] )
&& 'Outputs'[Date] > DATE ( 2019, 8, 1 )
)
)
)
If the above measure can't get your desired result, please provide some sample data of table Inputs and Outputs and your desired result with example. Thank you.
Best Regards
Community Support Team _ Rena Ruan
If this post helps, then please consider Accept it as the solution to help the other members find it more.
Hi @STS_Joshua
I don't know where your the start value of 10 is coming from . So I integrated it with the following solution:
Fin =
CALCULATE(
[Sum of Value],
FILTER(
ALL('Table'),
'Table'[Index] <= MIN('Table'[Index])
)
)
Sum of Value = SUM('Table'[In]) - SUM('Table'[Out])
With kind regards from the town where the legend of the 'Pied Piper of Hamelin' is at home
FrankAT (Proud to be a Datanaut)
Apologies, I should have been more explicit. 10 would be the value to start October with therefore it should be the final value for September. All of the month values are measures which are sums from their own respective tables like so:
Ins = SUM('Inputs'[Ins])
Outs = SUM('Outputs'[Outs])
The dates are a date table setup like so:
Dates = CALENDAR(FIRSTDATE('Inputs'[date]),LASTDATE('Inputs'[date]))
Final would then be a measure taking into account the Ins, Outs, and Current Inventory level that then works forward and back from the current Inventory because I have historical/projected ins and outs in their own respective tables.
Hi @STS_Joshua ,
Please try to create a measure as below:
Fin =
IF (
MAX ( 'Date'[Date] ) = DATE ( 2019, 8, 1 ), //Start date: 2019/08/01
12, //Initial Fin: 12
12
+ CALCULATE (
SUM ( 'Inputs'[Ins] ),
FILTER (
'Inputs',
'Inputs'[Date] <= MAX ( 'Date'[Date] )
&& 'Inputs'[Date] > DATE ( 2019, 8, 1 )
)
)
- CALCULATE (
SUM ( 'Outputs'[Outs] ),
FILTER (
'Outputs',
'Outputs'[Date] <= MAX ( 'Date'[Date] )
&& 'Outputs'[Date] > DATE ( 2019, 8, 1 )
)
)
)
If the above measure can't get your desired result, please provide some sample data of table Inputs and Outputs and your desired result with example. Thank you.
Best Regards
Community Support Team _ Rena Ruan
If this post helps, then please consider Accept it as the solution to help the other members find it more.
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
111 | |
82 | |
64 | |
53 | |
52 |
User | Count |
---|---|
128 | |
115 | |
80 | |
65 | |
63 |