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
Anonymous
Not applicable

DAX/Formula HELP!

Sorry for the vague subject - I am unsure how to categorize this. I am attempting to predict the inventory for the rest of the year. I currently have ending inventory data for months 1 through 5. To calculate the predicted inventory for the rest of the year, I need to take the previous month's ending inventory and add the Additional. However, this only works once. After that, I would need to self-reference the predicted ending inventory measure but this causes a circular reference. So - how do I perform this calculation?  Thank you!! 

 

MONTHBEG INVADDITIONALEND INVPredicted Ending Inventory
1100100200200
2200100300300
330050350350
4350200550550
555050600600
6 100 700
7 200 900
8 100 1000
9 100 1100
10 50 1150
11 100 1250
12 50 1300



1 ACCEPTED SOLUTION

@Anonymous try this measure

 

Measure 3 = 
SUMX ( 
    FILTER ( ALL ( Bal[MONTH] ), Bal[MONTH] <= MAX ( Bal[MONTH] ) ),
    CALCULATE ( SUM ( Bal[ADDITIONAL] ) ) 
)
+ CALCULATE ( SUM ( Bal[BEG INV] ), Bal[MONTH] = 1 )

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop shop for Power BI related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

View solution in original post

7 REPLIES 7
caochs
Regular Visitor

Hi @Anonymous - I see that you already marked the solution, but thought I'd share this measure with you any way.  Let me know if you have any questions:

caochs_0-1593462380446.png

 

 

 

Predicted Ending Inv = 
//Find the last month with an ending inventory for use later
VAR maxEndInvMonth =
    CALCULATE (
        MIN ( 'Table'[MONTH] ),
        FILTER ( ALL ( 'Table' ), ISBLANK ( 'Table'[END INV] ) )
    )
RETURN
    SUMX (
        ADDCOLUMNS (
            SUMMARIZE (
                'Table',
                'Table'[MONTH],
                'Table'[END INV],
                //Start the running total once there is no longer an ending inventory
                "RunningAdditionalNoEndingInventory", CALCULATE (
                    SUM ( 'Table'[ADDITIONAL] ),
                    FILTER (
                        ALL ( 'Table' ),
                        'Table'[MONTH] <= MAX ( 'Table'[MONTH] )
                            && 'Table'[MONTH] >= maxEndInvMonth
                    )
                )
            ),
            //This column is for demonstration purposes only and is not needed for the calculation
            "EarlierEndInv", CALCULATE (
                MAX ( 'Table'[END INV] ),
                FILTER ( 'table', 'table'[MONTH] < EARLIER ( 'table'[MONTH], 1 ) )
            ),
            //Check if the month has an ending inventory, if it does not then use the running total plus the "EARLIER" ending inventory.  If it has an ending inventory use that instead.
            "PredictedEndingInv", IF (
                CALCULATE ( MAX ( 'Table'[MONTH] ) ) >= maxEndInvMonth,
                CALCULATE (
                    MAX ( 'Table'[END INV] ),
                    FILTER ( ALL ( 'table' ), 'table'[MONTH] < EARLIER ( 'table'[MONTH], 1 ) )
                ) + [RunningAdditionalNoEndingInventory],
                'Table'[END INV]
            )
        ),
        [PredictedEndingInv]
    )

 

Anonymous
Not applicable

@caochs thank you!!! Very helpful.

parry2k
Super User
Super User

@Anonymous you are pretty much looking for running total

 

Predicted Ending Inventory = 
CALCULATE ( 
SUM ( Table[Beg Inv] ) +
SUM ( Table[Additionaol ),
FILTER ( 
ALL ( Table ),
Table[Month] <= MAX ( Table[Month] )
)

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop shop for Power BI related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Anonymous
Not applicable

@parry2k thanks for the response.  I think this is in the right direction, however, my results were as follows:

 

MONTHBEG INVADDITIONALEND INVPredicted Ending InventoryPARRY2K FORMULA
1100100200200200
2200100300300500
330050350350850
43502005505501400
5550506006002000
6 100 7002100
7 200 9002300
8 100 10002400
9 100 11002500
10 50 11502550
11 100 12502650
12 50 13002700

Hi @Anonymous ,

 

Create a new blank query and paste this mcode to create a recursive function:

 

(_table as table, _month as number, _currentMonth as number, _inventoryValue as number) as number =>
let
Source = Table.SelectRows(_table, each [MONTH] = _month),
BEG_INV = if Source[BEG INV]{0} = null or _month > 1 then 0 else Source[BEG INV]{0},
ADDITIONAL = if Source[ADDITIONAL]{0} = null then 0 else Source[ADDITIONAL]{0},
PredictValue = _inventoryValue + ADDITIONAL + BEG_INV,
Result = if _month < _currentMonth then @fn_PredictValues(_table, _month + 1, _currentMonth, PredictValue) else PredictValue
in
Result

Capture.PNG

 

Use this mcode to create your base table:

 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bcxBCsAgDATAr0jOOSSxse1bxP9/Q7GrSMllWYZNaiUlJhXZaSMbVzL05Rme0Zl8sn98oa8jhzs65gVfyuhp/07Tbpgd9gS7NzAVoB+m0dB+w9YB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [MONTH = _t, #"BEG INV" = _t, ADDITIONAL = _t, #"END INV" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"MONTH", Int64.Type}, {"BEG INV", Int64.Type}, {"ADDITIONAL", Int64.Type}, {"END INV", Int64.Type}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each fn_PredictValues(#"Changed Type", 1, [MONTH], 0))
in
#"Added Custom"

 

or create a custom column like this:

 

Capture.PNGCapture1.PNG

 

 



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

Proud to be a Super User!



@Anonymous try this measure

 

Measure 3 = 
SUMX ( 
    FILTER ( ALL ( Bal[MONTH] ), Bal[MONTH] <= MAX ( Bal[MONTH] ) ),
    CALCULATE ( SUM ( Bal[ADDITIONAL] ) ) 
)
+ CALCULATE ( SUM ( Bal[BEG INV] ), Bal[MONTH] = 1 )

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop shop for Power BI related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Anonymous
Not applicable

Awesome - thank you so much!

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.