Forecasting Opening and Closing Inventory
Results 1 to 5 of 5

Thread: Forecasting Opening and Closing Inventory
Thanks Thanks: 0 Likes Likes: 0

  1. #1
    New Member
    Join Date
    Mar 2019
    Posts
    5
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Forecasting Opening and Closing Inventory

    Hello all,
    new to the forum.
    I have an issue with powerpivot/DAX that I have not been able to solve. I hope someone is up for the challenge...

    The problem is calculating a YTD monthly Inventory closing position while ignoring cumulative negatives if there is no stock to satisfy the forecast.
    Kind of hard to explain but the attached file shows my desired outcome.


    Im using the following
    InvMovement:=[PURCHASES]-[SALES]
    OPENING INV:=calculate([InvMovement],FILTER(ALL(‘DATE'[DATE]),’DATE'[DATE]< MAX(‘DATE'[DATE])))+[CURRINV]
    ENDING INV:=calculate([InvMovement],FILTER(ALL(‘DATE'[DATE]),’DATE'[DATE]<= MAX(‘DATE'[DATE])))+[CURRINV]

    the problem is that there cases where my Sales Team is forecasting above the available inventory in a future period.
    When we are out of Stock we still want the forecast to remain, even though we cant fill the sale.
    The above OPENING INV and ENDING INV calculations work when inventory is always positive, but accumulates the negatives on Out of Stocks and results in incorrect (negative) opening inventory positions.

    Id like the ENDING INV results to be 0 if it calculates as negative and OPENING INV of the following period to also be zero.
    link to my file below

    https://1drv.ms/x/s!AgsUyh0i7varnjMfLmnZ1bPgSSGp

    THANKS!!!

  2. #2
    Board Regular
    Join Date
    Dec 2013
    Location
    Auckland, New Zealand
    Posts
    263
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Forecasting Opening and Closing Inventory

    Hello gkaropo

    Welcome to the forum

    I have uploaded an edited version of your file here.

    The logic I have used here (and in similar situations in the past)
    1. Based on the original inflows/outflows, find the most negative inventory balance that has occurred to date.
    2. Add this back to the originally calculated inventory balance


    I created some additional measures to handle this and modified your existing measures. The resulting measures are:
    Code:
    ENDING INV UNADJUSTED =
    CALCULATE (
        [InvMovement],
        FILTER ( ALL ( 'DATE'[DATE] ), 'DATE'[DATE] <= MAX ( 'DATE'[DATE] ) )
    ) + [CURRINV]
    
    Most negative ENDING INV UNADJUSTED so far =
    MINX (
        FILTER ( ALL ( 'DATE'[DATE] ), 'DATE'[DATE] <= MAX ( 'DATE'[DATE] ) ),
        MIN ( [ENDING INV UNADJUSTED], 0 )
    )
    
    ENDING INV =
    [ENDING INV UNADJUSTED] - [Most negative ENDING INV UNADJUSTED so far]
    
    OPENING INV =
    CALCULATE (
        [ENDING INV],
        FILTER ( ALL ( 'DATE'[DATE] ), 'DATE'[DATE] < MAX ( 'DATE'[DATE] ) )
    )
    // I think it's always best to calculate OPENING INV as ENDING INV in the previous period
    Regards,
    Owen
    Last edited by Ozeroth; Mar 18th, 2019 at 07:40 AM.

  3. #3
    New Member
    Join Date
    Mar 2019
    Posts
    5
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Forecasting Opening and Closing Inventory

    Hi Owen,

    thanks so much for this. I replicated this on my main dataset and am getting an error. I opened the file that you saved and if i refresh the pivot, the same error comes up.

    "The measure 'DATA'[ENDING INV] depends on another measure named 'DATA'[Most negative ENDING INV UNADJUSTED so far] which has an error: Too many arguments were passed to the MIN function. The max argument count for the function is 1.

    thanks again...

  4. #4
    Board Regular
    Join Date
    Dec 2013
    Location
    Auckland, New Zealand
    Posts
    263
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Forecasting Opening and Closing Inventory

    Hi again gkaropo,

    It sounds like you're using Excel 2013 - I should have checked
    In the Excel 2013 version of Power Pivot, the MIN function only works with a single column but not with two scalars .

    You just need to change the Most negative ENDING INV UNADJUSTED so far measure as follows (I have done this in my uploaded file as well):
    Code:
    Most negative ENDING INV UNADJUSTED so far =
    MINX (
        FILTER ( ALL ( 'DATE'[DATE] ), 'DATE'[DATE] <= MAX ( 'DATE'[DATE] ) ),
        IF ( [ENDING INV UNADJUSTED] < 0, [ENDING INV UNADJUSTED], 0 )
    )
    Regards,
    Owen

  5. #5
    New Member
    Join Date
    Mar 2019
    Posts
    5
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Forecasting Opening and Closing Inventory

    Owen. You are a rockstar!
    thank you!

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •