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

Calculation of inventory forecast coverage

Hi Everyone,

 

I was making a visualization model for forecasting analysis and one of the measure is forecast coverage for various items. Following is a sample data.

 

Item NoOn-hand InventoryM+1M+2M+3M+4M+5M+6M+7M+8M+9M+10M+11M+12Forecast Coverage (Day)
 S1             500                       50                      120                   100                      80                170             210                130              110                140                162                  90              70          148.42  
 S2          1,500                     100                      100                   100                    100                200             200                100              150                150                150                150            200          334.40  
 S3          2,500                  1,500                   1,700                2,100                 1,500             1,400               -                    -                  -                    -                    -                    -                -             48.28  
All SKUS         4,500                  1,650                   1,920                2,300                 1,680             1,770             410                230              260                290                312                240            270                73.09 

 

Assuming number of days in each month is 30.4, formula= (number of months covered - 1)*30.4 + (remaining inventory/ demand in last covered month)*30.4

 

Overall coverage shall be the value calculated from total on-hand inventory and overall forecasted demands in each month, instead of average value.

 

I have made a unpivoted table and calculated cumulative sum of forecasted demand with reference to following post. 

https://community.powerbi.com/t5/Desktop/Weeks-of-inventory-forecast-coverage/td-p/725459 

 

But I cannot figure out how to make the calculation in term of days. Thank you so much for any solution provided!

 

1 ACCEPTED SOLUTION
edhans
Super User
Super User

@Anonymous you really need a date table for this.
First I had to make some assumptions. The on hand was current month, then M+1 meant next month, M+2 meant 2 months from now, etc. Then I converted those to dates by unpivoting. Full code here:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCjZU0lEyNDAAksYgwsRAKVYHKGwEZBtBhE1BwiZKsbEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Item = _t, OH = _t, #"M+1" = _t, #"M+2" = _t]),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(Source, {"Item"}, "Attribute", "Value"),
    #"Extracted Text After Delimiter" = Table.TransformColumns(#"Unpivoted Other Columns", {{"Attribute", each Text.AfterDelimiter(_, "+"), type text}}),
    #"Changed Type" = Table.TransformColumnTypes(#"Extracted Text After Delimiter",{{"Attribute", Int64.Type}, {"Value", Int64.Type}}),
    #"Added Date" = 
        Table.AddColumn(
            #"Changed Type", 
            "Date", 
            each 
                Date.AddMonths(
                    Date.EndOfMonth(
                        DateTime.Date(
                            DateTime.LocalNow()
                            )
                        ), (if [Attribute] = null then 0 else [Attribute])
                ),
            Date.Type
        ),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Date",{"Item", "Date", "Value"})

in
    #"Removed Other Columns"

That turns this:

edhans_0-1610472290579.png

into this:

edhans_1-1610472314143.png

I couldn't use your original data. It was just one long string of text. See links below for putting data in usable tables.

Then I added a date table to Power Query using this code, and changed the SOURCE line to be just Jan 1, 2021-Dec 31, 2021.

Finally, by creating a few relatively simple measures, I was able to create a Table Visual that looks like this:

edhans_2-1610472445806.png

Now we can count exact days in the month and do whatever you need. Rather than post those measures, just get my PBIX file here. It has everything in it.

 

If you need further help, please provide good data and expected results per info here:

How to get good help fast. Help us help you.
How to Get Your Question Answered Quickly - Give us a good and concise explanation
How to provide sample data in the Power BI Forum - Provide data in a table format per the link, or share an Excel/CSV file via OneDrive, Dropbox, etc.. Provide expected output using a screenshot of Excel or other image. Do not provide a screenshot of the source data. I cannot paste an image into Power BI tables.

 

 

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

View solution in original post

1 REPLY 1
edhans
Super User
Super User

@Anonymous you really need a date table for this.
First I had to make some assumptions. The on hand was current month, then M+1 meant next month, M+2 meant 2 months from now, etc. Then I converted those to dates by unpivoting. Full code here:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCjZU0lEyNDAAksYgwsRAKVYHKGwEZBtBhE1BwiZKsbEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Item = _t, OH = _t, #"M+1" = _t, #"M+2" = _t]),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(Source, {"Item"}, "Attribute", "Value"),
    #"Extracted Text After Delimiter" = Table.TransformColumns(#"Unpivoted Other Columns", {{"Attribute", each Text.AfterDelimiter(_, "+"), type text}}),
    #"Changed Type" = Table.TransformColumnTypes(#"Extracted Text After Delimiter",{{"Attribute", Int64.Type}, {"Value", Int64.Type}}),
    #"Added Date" = 
        Table.AddColumn(
            #"Changed Type", 
            "Date", 
            each 
                Date.AddMonths(
                    Date.EndOfMonth(
                        DateTime.Date(
                            DateTime.LocalNow()
                            )
                        ), (if [Attribute] = null then 0 else [Attribute])
                ),
            Date.Type
        ),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Date",{"Item", "Date", "Value"})

in
    #"Removed Other Columns"

That turns this:

edhans_0-1610472290579.png

into this:

edhans_1-1610472314143.png

I couldn't use your original data. It was just one long string of text. See links below for putting data in usable tables.

Then I added a date table to Power Query using this code, and changed the SOURCE line to be just Jan 1, 2021-Dec 31, 2021.

Finally, by creating a few relatively simple measures, I was able to create a Table Visual that looks like this:

edhans_2-1610472445806.png

Now we can count exact days in the month and do whatever you need. Rather than post those measures, just get my PBIX file here. It has everything in it.

 

If you need further help, please provide good data and expected results per info here:

How to get good help fast. Help us help you.
How to Get Your Question Answered Quickly - Give us a good and concise explanation
How to provide sample data in the Power BI Forum - Provide data in a table format per the link, or share an Excel/CSV file via OneDrive, Dropbox, etc.. Provide expected output using a screenshot of Excel or other image. Do not provide a screenshot of the source data. I cannot paste an image into Power BI tables.

 

 

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

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.

Top Solution Authors
Top Kudoed Authors