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
jaco1951
Helper III
Helper III

Subtotals etc. How can I create a detailed forecast report

Hi

 

I have a startbalance from my bank and from reports coming from other offices. Based on this start balance I want to create a 5-week forecast model where I use incoming and outging this week to create a new start balance next week, and so on...

I also do need the granularity so that I can filter and see where the data are coming from.

I have been struggeling with this issue for quite a while, and I have a previously post that was solved, but since my test data were trimmed down too much, I still face new challenges.

My previous post

 

I have created a much more detailed data set here:

 

detailed data set

My problem was elegantly solved with the previous data set, but as I added more details like currency, bank accounts, invoice number etc, the granularity exploded and the original formulas doesn't work anymore.

I have tried to modify the formulas that   created, but I am not able to get a correct result anymore.

Here is what i get when I put the data into a cross tabel without doing any changes:

Capture 4.JPG

I need to find a way to bring the first week total on to the next week start balance.

Like this:

Capture 5.JPG

I would like to be able to filter an all these fields:
Capture 6.JPG


All help is much appreciated 🙂

Br Espen

1 ACCEPTED SOLUTION

Hi Espen,

 

Try this formula please.

Measure 3 =
VAR currentWeek =
    MIN ( Sheet1[4week] )
VAR minWeek =
    CALCULATE ( MIN ( Sheet1[4week] ), ALLSELECTED ( Sheet1[4week] ) )
VAR initialStartBalance =
    CALCULATE (
        SUM ( Sheet1[amount_USD] ),
        Sheet1[4week] = minWeek,
        Sheet1[forecast_category] = "1. StartBalance"
    )
RETURN
    IF (
        minWeek = currentWeek,
        SUM ( Sheet1[amount_USD] ),
        IF (
            HASONEVALUE ( Sheet1[forecast_category] )
                && MIN ( Sheet1[forecast_category] ) <> "1. StartBalance",
            SUM ( Sheet1[amount_USD] ),
            IF (
                HASONEVALUE ( Sheet1[forecast_category] )
                    && MIN ( Sheet1[forecast_category] ) = "1. StartBalance",
                initialStartBalance
                    + CALCULATE (
                        SUM ( Sheet1[amount_USD] ),
                        Sheet1[forecast_category] IN { "2. Incoming", "3. Outgoing" },
                        Sheet1[4week] < currentWeek
                    ),
                initialStartBalance
                    + CALCULATE (
                        SUM ( Sheet1[amount_USD] ),
                        Sheet1[forecast_category] IN { "2. Incoming", "3. Outgoing" },
                        Sheet1[4week] <= currentWeek
                    )
            )
        )
    )

Subtotals_etc2

 

 

Best Regards,

Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

6 REPLIES 6
v-jiascu-msft
Employee
Employee

Hi @jaco1951,

 

Try this formula please. Please also check out the demo in the attachment.

Measure =
VAR currentWeek =
    MIN ( Sheet1[4week] )
VAR minWeek =
    CALCULATE ( MIN ( Sheet1[4week] ), ALLSELECTED ( Sheet1[4week] ) )
RETURN
    IF (
        minWeek = currentWeek,
        SUM ( Sheet1[amount_USD] ),
        IF (
            HASONEVALUE ( Sheet1[forecast_category] )
                && MIN ( Sheet1[forecast_category] ) = "1. StartBalance",
            CALCULATE (
                SUM ( Sheet1[amount_USD] ),
                ALL ( Sheet1[forecast_category] ),
                Sheet1[4week]
                    = currentWeek - 1
            ),
            SUM ( Sheet1[amount_USD] )
        )
    )

Subtotals_etc

 

Best Regards,

Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thank you very much Dale; @v-jiascu-msft I discovered that there is something wrong with the summarizing, if you look at week 2-5 the totals are not correct. For example the Total of week 2 should be close to 6.5M, but it shows about 1M:

2.JPG1.JPG
Best regards

Espen

Hi Espen,

 

You mean you need to add the new values. Please try the formula below. It could be a little long.

Measure 2 =
VAR currentWeek =
    MIN ( Sheet1[4week] )
VAR minWeek =
    CALCULATE ( MIN ( Sheet1[4week] ), ALLSELECTED ( Sheet1[4week] ) )
RETURN
    IF (
        minWeek = currentWeek,
        SUM ( Sheet1[amount_USD] ),
        IF (
            HASONEVALUE ( Sheet1[forecast_category] )
                && MIN ( Sheet1[forecast_category] ) = "1. StartBalance",
            CALCULATE (
                SUM ( Sheet1[amount_USD] ),
                ALL ( Sheet1[forecast_category] ),
                Sheet1[4week]
                    = currentWeek - 1
            ),
            IF (
                HASONEVALUE ( Sheet1[forecast_category] ),
                SUM ( Sheet1[amount_USD] ),
                CALCULATE (
                    SUM ( Sheet1[amount_USD] ),
                    FILTER ( ALL ( Sheet1[4week] ), 'Sheet1'[4week] <= MAX ( 'Sheet1'[4week] ) )
                )
                    - CALCULATE (
                        SUM ( Sheet1[amount_USD] ),
                        Sheet1[forecast_category] = "1. StartBalance"
                    )
            )
        )
    )

Best Regards,

Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thank you very much Dale for spending time on this one, I cannot get the values to add quite up. But the values are correct in week 1 and 2, but then in week 3 it gets a bit strange. 

You can see the new measure added into the file:

 

 Measure2 in use


My idea is to see the Totals reflect the net value from "StartBalance + Incoming - Outgoing", and then find this value as a startbalance for the next week in the forcast:

 

Capture 6.JPG

Best regards 

Espen

Hi Espen,

 

Try this formula please.

Measure 3 =
VAR currentWeek =
    MIN ( Sheet1[4week] )
VAR minWeek =
    CALCULATE ( MIN ( Sheet1[4week] ), ALLSELECTED ( Sheet1[4week] ) )
VAR initialStartBalance =
    CALCULATE (
        SUM ( Sheet1[amount_USD] ),
        Sheet1[4week] = minWeek,
        Sheet1[forecast_category] = "1. StartBalance"
    )
RETURN
    IF (
        minWeek = currentWeek,
        SUM ( Sheet1[amount_USD] ),
        IF (
            HASONEVALUE ( Sheet1[forecast_category] )
                && MIN ( Sheet1[forecast_category] ) <> "1. StartBalance",
            SUM ( Sheet1[amount_USD] ),
            IF (
                HASONEVALUE ( Sheet1[forecast_category] )
                    && MIN ( Sheet1[forecast_category] ) = "1. StartBalance",
                initialStartBalance
                    + CALCULATE (
                        SUM ( Sheet1[amount_USD] ),
                        Sheet1[forecast_category] IN { "2. Incoming", "3. Outgoing" },
                        Sheet1[4week] < currentWeek
                    ),
                initialStartBalance
                    + CALCULATE (
                        SUM ( Sheet1[amount_USD] ),
                        Sheet1[forecast_category] IN { "2. Incoming", "3. Outgoing" },
                        Sheet1[4week] <= currentWeek
                    )
            )
        )
    )

Subtotals_etc2

 

 

Best Regards,

Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi Dale

 

This is excellent, I really appreciate your work solving the problem for me. 🙂

If I may ask a follow up question, some of the companies in "%Comp" do only have values in the first week in the field "1. StartBalance".

If I make a filter and select this company only, there are no values in the "1. StartBalance" row of the remaining weeks. The sub totals are correct though.

Do you know a solution to how I could "fill in the blanks"?

 

 

Capture 7.JPG

 

Best regards Espen

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.