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
jamaza
New Member

Line Graph - Actuals extended by Forecast

Hello

 

I have a line graph which contains actuals up to current month, and would like to extend this line with forecast values that I have.

https://imgur.com/09xuTT6

 

I have measures setup as follows to do a cumulative sums, this is one for fees rendered:

Fees Rendered =
Calculate(
SUM('Job'[FeesInvoiced]) + SUM('Job'[ExpensesInvoiced]),
FILTER(
ALLSELECTED('Job'),
'Job'[FinancialPeriod] <= max('Job'[FinancialPeriod])
)
)
 
The other measure is the same just pointing to the other table.
 
i've attempted to add the 2 measures together, but once it gets to the end of actuals period, it only takes cumulative of the other table, i need it to still maintain cumulative sum of the first table.
 
This could probably be solved with appending the data, but i really don't want to do that due to the setup of the data
 
Thanks
1 ACCEPTED SOLUTION
v-zhenbw-msft
Community Support
Community Support

Hi @jamaza ,

 

We can create a measure to meet your requirement.

 

1. At first, we need to create a relationship between two tables.

 

Line1.jpg

 

2. Then we can create a measure like this,

 

Measure = 
VAR max_period =
    MAXX ( ALLSELECTED ( Job ), Job[FinancialPeriod] )
VAR sum_ = [Fees Rendered] + [Fees Rendered 2]
VAR x =
    CALCULATE (
        [Fees Rendered],
        FILTER ( ALLSELECTED ( Job ), Job[FinancialPeriod] <= max_period )
    )
VAR y =
    CALCULATE (
        [Fees Rendered 2],
        FILTER ( ALLSELECTED ( 'Table' ), 'Table'[FinancialPeriod] <= max_period )
    )
RETURN
IF ( ISBLANK ( [Fees Rendered] ), x + y + [Fees Rendered 2], sum_ )

 

3. At last we can create a line chart ( We need to use the longest FinancialPeriod for X axis ), the result like this,

 

Line2.jpg

 

If it doesn’t meet your requirement, could you please provide a mockup sample  based on the table that we have shared or describe the fields of each tables and the relations between tables simply?

 

It will be helpful if you can show us the exact expected result based on the tables.

 

Please upload your files to OneDrive For Business and share the link here. Please don't contain any Confidential Information or Real data in your reply.

BTW, pbix as attached.

 

Best regards,

 

Community Support Team _ zhenbw

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

2 REPLIES 2
v-zhenbw-msft
Community Support
Community Support

Hi @jamaza ,

 

We can create a measure to meet your requirement.

 

1. At first, we need to create a relationship between two tables.

 

Line1.jpg

 

2. Then we can create a measure like this,

 

Measure = 
VAR max_period =
    MAXX ( ALLSELECTED ( Job ), Job[FinancialPeriod] )
VAR sum_ = [Fees Rendered] + [Fees Rendered 2]
VAR x =
    CALCULATE (
        [Fees Rendered],
        FILTER ( ALLSELECTED ( Job ), Job[FinancialPeriod] <= max_period )
    )
VAR y =
    CALCULATE (
        [Fees Rendered 2],
        FILTER ( ALLSELECTED ( 'Table' ), 'Table'[FinancialPeriod] <= max_period )
    )
RETURN
IF ( ISBLANK ( [Fees Rendered] ), x + y + [Fees Rendered 2], sum_ )

 

3. At last we can create a line chart ( We need to use the longest FinancialPeriod for X axis ), the result like this,

 

Line2.jpg

 

If it doesn’t meet your requirement, could you please provide a mockup sample  based on the table that we have shared or describe the fields of each tables and the relations between tables simply?

 

It will be helpful if you can show us the exact expected result based on the tables.

 

Please upload your files to OneDrive For Business and share the link here. Please don't contain any Confidential Information or Real data in your reply.

BTW, pbix as attached.

 

Best regards,

 

Community Support Team _ zhenbw

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

Hi @v-zhenbw-msft ,

 

Thank you so much for taking the time to assist me - the DAX you wrote worked perfectly in terms of joining the cumulative values of both tables. The only hickup i've encountered is that i am displayed with periods before and after the projects data

https://imgur.com/Z7RCoPT

 

I have 1 table of all periods

"Actuals" table also contains periods up to current month

"Forecast" table contains periods from current month

 

Is it possible to tweak the DAX so that it provides periods from MIN Period of "Actuals" and MAX Period of "Forecast" ? this would cover the whole data range required to be displayed on the graph.

 

My current DAX is as follows:

Actuals+Forecast =
VAR max_period =
MAXX ( ALLSELECTED ( 'F-JobFinancialPeriod' ), 'F-JobFinancialPeriod'[FinancialPeriod] )
VAR sum_ = [Fees Rendered] + [Forecast]
VAR x =
CALCULATE (
[Fees Rendered],
FILTER ( ALLSELECTED ( 'F-JobFinancialPeriod' ), 'F-JobFinancialPeriod'[FinancialPeriod] <= max_period )
)
VAR y =
CALCULATE (
[Forecast],
FILTER ( ALLSELECTED ( 'PFF' ), 'PFF'[Period] <= max_period )
)
RETURN
IF ( ISBLANK ( [Fees Rendered] ), x + y + [Forecast], sum_ )

 

 

Thanks again for your assistance!

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.