cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
jakesolty
New Member

Struggling to break down values into yearly amounts. eg. Pipeline forecasting

Good day to you all,

 

I'm really struggling with trying to find the correct dax to use to break down a forecast pipeline into yearly amounts. We have multiple projects that start and end at different times. Please see below an example of how I need it to look in a table within Power Bi.

 

Excel example

 

The columns without formatting is the information I already have and the blue shaded area is what I need to replicate.

 

Any advice would be much appreciated

 

Thanks, Jake

 

*Construction Length and Management Length are in months

1 ACCEPTED SOLUTION
v-huizhn-msft
Microsoft
Microsoft

Hi @jakesolty,

I try to reproduce your scenario, please create the calculated column use the following formula.

2017 =
IF (
    YEAR (
        DATE ( YEAR ( Test[Start of Construction] ), MONTH ( Test[Start of Construction] ) + Test[Construction Length], DAY ( Test[Start of Construction] ) )
    )
        = 2017,
    Test[Construction Length] * Test[Construction p/m],
    IF (
        YEAR ( Test[Start of Construction] ) = 2017,
        IF (
            (
                DATEDIFF ( Test[Start of Construction], DATE ( 2018, 1, 1 ), MONTH )
                    <= Test[Construction Length]
            ),
            DATEDIFF ( Test[Start of Construction], DATE ( 2018, 1, 1 ), MONTH )
                * Test[Construction p/m],
            BLANK ()
        ),
        BLANK ()
    )
        + IF (
            YEAR ( Test[Start of Management] ) = 2017,
            IF (
                (
                    DATEDIFF ( Test[Start of Management], DATE ( 2018, 1, 1 ), MONTH )
                        <= Test[Management Length]
                ),
                DATEDIFF ( Test[Start of Management], DATE ( 2018, 1, 1 ), MONTH )
                    * Test[Management p/m],
                BLANK ()
            ),
            BLANK ()
        )
)


1.PNG

2018 =
IF (
    2018
        < YEAR (
            DATE ( YEAR ( Test[Start of Construction] ), MONTH ( Test[Start of Construction] ) + Test[Construction Length], DAY ( Test[Start of Construction] ) )
        ),
    IF (
        YEAR ( Test[Start of Construction] ) = 2017,
        IF (
            MONTH ( Test[Start of Construction] ) = 1,
            DATEDIFF ( Test[Start of Construction], DATE ( 2018, 12, 31 ), MONTH ) + 1,
            DATEDIFF ( Test[Start of Construction], DATE ( 2018, 12, 31 ), MONTH )
        )
            * Test[Construction p/m]
            - Test[2017],
        IF (
            MONTH ( Test[Start of Construction] ) = 1,
            DATEDIFF ( Test[Start of Construction], DATE ( 2018, 12, 31 ), MONTH ) + 1,
            DATEDIFF ( Test[Start of Construction], DATE ( 2018, 12, 31 ), MONTH )
        )
            * Test[Construction p/m]
    ),
    BLANK ()
)

2.PNG

For 2019 and 2019+, you can use the similar method to get. 

Best Regards,
Angelia

View solution in original post

2 REPLIES 2
v-huizhn-msft
Microsoft
Microsoft

Hi @jakesolty,

I try to reproduce your scenario, please create the calculated column use the following formula.

2017 =
IF (
    YEAR (
        DATE ( YEAR ( Test[Start of Construction] ), MONTH ( Test[Start of Construction] ) + Test[Construction Length], DAY ( Test[Start of Construction] ) )
    )
        = 2017,
    Test[Construction Length] * Test[Construction p/m],
    IF (
        YEAR ( Test[Start of Construction] ) = 2017,
        IF (
            (
                DATEDIFF ( Test[Start of Construction], DATE ( 2018, 1, 1 ), MONTH )
                    <= Test[Construction Length]
            ),
            DATEDIFF ( Test[Start of Construction], DATE ( 2018, 1, 1 ), MONTH )
                * Test[Construction p/m],
            BLANK ()
        ),
        BLANK ()
    )
        + IF (
            YEAR ( Test[Start of Management] ) = 2017,
            IF (
                (
                    DATEDIFF ( Test[Start of Management], DATE ( 2018, 1, 1 ), MONTH )
                        <= Test[Management Length]
                ),
                DATEDIFF ( Test[Start of Management], DATE ( 2018, 1, 1 ), MONTH )
                    * Test[Management p/m],
                BLANK ()
            ),
            BLANK ()
        )
)


1.PNG

2018 =
IF (
    2018
        < YEAR (
            DATE ( YEAR ( Test[Start of Construction] ), MONTH ( Test[Start of Construction] ) + Test[Construction Length], DAY ( Test[Start of Construction] ) )
        ),
    IF (
        YEAR ( Test[Start of Construction] ) = 2017,
        IF (
            MONTH ( Test[Start of Construction] ) = 1,
            DATEDIFF ( Test[Start of Construction], DATE ( 2018, 12, 31 ), MONTH ) + 1,
            DATEDIFF ( Test[Start of Construction], DATE ( 2018, 12, 31 ), MONTH )
        )
            * Test[Construction p/m]
            - Test[2017],
        IF (
            MONTH ( Test[Start of Construction] ) = 1,
            DATEDIFF ( Test[Start of Construction], DATE ( 2018, 12, 31 ), MONTH ) + 1,
            DATEDIFF ( Test[Start of Construction], DATE ( 2018, 12, 31 ), MONTH )
        )
            * Test[Construction p/m]
    ),
    BLANK ()
)

2.PNG

For 2019 and 2019+, you can use the similar method to get. 

Best Regards,
Angelia

Thanks for the speedy response, I will check this now.

Helpful resources

Announcements
September Update

Check it Out!

Click here to learn more about the September 2022 updates!

Power BI Show Episode 10 Recap

The Power BI Community Show

Watch the playback when Amit Chandak, a Power BI Super User, demos how to use Field Parameters to make reports more dynamic.

Power BI Dev Camp Session 26

New Date - Check it Out!

Mark your calendars and join us on Thursday, October 6 at 11a PDT for a great session with Ted Pattison!

Health and Life Sciences Power BI User Group

Health and Life Sciences Power BI User Group

Power BI specialists at Microsoft have created a community user group where customers in the provider, payor, pharma, health solutions, and life science industries can collaborate.

Top Solution Authors