March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe 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
Hi All,
I have a problem i have run into when trying to create a running total of "line of balance" (LoB)
The calcualtion for month 1 is ([total stock] + [purchases]) - [usage].
Then the following month the calculation will use the previous months output and then calculate the current months purchases - the current month usage
hope this makes sense?
I have 3 tables (Stock, Purchases, Usage) and what i want to do is create a running Line Of Balance visual in power BI;
Stock;
Material | Stock on Hand |
A | 100 |
B | 500 |
C | 1000 |
Purchases
Material | PurchDate | Quantity |
A | 01/01/2023 | 10 |
A | 01/02/2023 | 20 |
B | 01/01/2023 | 10 |
B | 01/02/2023 | 20 |
C | 01/01/2023 | 10 |
C | 01/02/2023 | 20 |
Usage
Material | UseageDate | Quantity |
A | 01/01/2023 | 50 |
A | 01/02/2023 | 10 |
B | 01/01/2023 | 100 |
B | 01/02/2023 | 10 |
C | 01/01/2023 | 300 |
C | 01/02/2023 | 20 |
what i want to do is create a table within power bi that outputs a visual with a running total calculated like the below. I have a calendar table already created:
Material | 01/01/2023 | 01/02/2023 |
A | 60 | 70 |
B | 410 | 420 |
C | 710 | 710 |
(Stock on hand + Purch) - Usage | (Previous month LoB + Purchases) - usage |
hope you can help
many thanks,
J
Solved! Go to Solution.
Hi @Jtbonner1986 ,
I created a sample pbix file(see the attachment), please check if that is what you want.
Measure =
VAR _selmatrial =
SELECTEDVALUE ( 'Stock'[Material] )
VAR _seldate =
SELECTEDVALUE ( 'Calendar'[Date] )
VAR _stock =
SUM ( 'Stock'[Stock on Hand] )
VAR _purchase =
CALCULATE (
SUM ( 'Purchases'[Quantity] ),
FILTER ( 'Purchases', 'Purchases'[PurchDate] = _seldate )
)
VAR _usage =
CALCULATE (
SUM ( 'Usage'[Quantity] ),
FILTER ( 'Usage', 'Usage'[UseageDate] = _seldate )
)
VAR _prempurchase =
CALCULATE (
SUM ( 'Purchases'[Quantity] ),
FILTER (
'Purchases',
YEAR ( 'Purchases'[PurchDate] )
= YEAR ( _seldate - 1 )
&& MONTH ( 'Purchases'[PurchDate] )
= MONTH ( _seldate - 1 )
)
)
VAR _premusage =
CALCULATE (
SUM ( 'Usage'[Quantity] ),
FILTER (
'Usage',
YEAR ( 'Usage'[UseageDate] )
= YEAR ( _seldate - 1 )
&& MONTH ( 'Usage'[UseageDate] )
= MONTH ( _seldate - 1 )
)
)
RETURN
_stock + _purchase - ( _premusage - _prempurchase ) - _usage
If the above ones can't help you, could you please provide some raw data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples? By the way, what kind of conditions are needed for different background colors? It would be helpful to find out the solution. You can refer the following links to share the required info:
How to provide sample data in the Power BI Forum
How to Get Your Question Answered Quickly
And It is better if you can share a simplified pbix file. You can refer the following link to upload the file to the community. Thank you.
How to upload PBI in Community
Best Regards
Hi
Thanks so much for the response. So sorry it has taken me this long to reply. Sickness and other things have gotten in the way
Okay, so the example file is exactly what i want.
However when applying this to my dataset the results are not coming back as expected. I am not sure if this is because of the dates where there is no 'usage' or 'demand' and the calcualtion the resets to the original 'stock on hand'?
Any help is grately appreciated
Many thanks,
Josh
Hi @Jtbonner1986 ,
I created a sample pbix file(see the attachment), please check if that is what you want.
Measure =
VAR _selmatrial =
SELECTEDVALUE ( 'Stock'[Material] )
VAR _seldate =
SELECTEDVALUE ( 'Calendar'[Date] )
VAR _stock =
SUM ( 'Stock'[Stock on Hand] )
VAR _purchase =
CALCULATE (
SUM ( 'Purchases'[Quantity] ),
FILTER ( 'Purchases', 'Purchases'[PurchDate] = _seldate )
)
VAR _usage =
CALCULATE (
SUM ( 'Usage'[Quantity] ),
FILTER ( 'Usage', 'Usage'[UseageDate] = _seldate )
)
VAR _prempurchase =
CALCULATE (
SUM ( 'Purchases'[Quantity] ),
FILTER (
'Purchases',
YEAR ( 'Purchases'[PurchDate] )
= YEAR ( _seldate - 1 )
&& MONTH ( 'Purchases'[PurchDate] )
= MONTH ( _seldate - 1 )
)
)
VAR _premusage =
CALCULATE (
SUM ( 'Usage'[Quantity] ),
FILTER (
'Usage',
YEAR ( 'Usage'[UseageDate] )
= YEAR ( _seldate - 1 )
&& MONTH ( 'Usage'[UseageDate] )
= MONTH ( _seldate - 1 )
)
)
RETURN
_stock + _purchase - ( _premusage - _prempurchase ) - _usage
If the above ones can't help you, could you please provide some raw data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples? By the way, what kind of conditions are needed for different background colors? It would be helpful to find out the solution. You can refer the following links to share the required info:
How to provide sample data in the Power BI Forum
How to Get Your Question Answered Quickly
And It is better if you can share a simplified pbix file. You can refer the following link to upload the file to the community. Thank you.
How to upload PBI in Community
Best Regards
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
129 | |
90 | |
75 | |
58 | |
53 |
User | Count |
---|---|
200 | |
104 | |
101 | |
67 | |
55 |