Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
carlenb
Advocate II
Advocate II

Cumulative progress chart [Model attached]

Hi,

 

See model with test data here:

https://drive.google.com/file/d/1S4G3rC5-SAothJEkQBq2DhXRtWXrM9a3/view?usp=drivesdk

 

Outout: I want to create the following graph

 

carlenb_1-1711533646432.png

Test data used in model 

 

Contract scheduled doneReschedule 1Reschedule 2StatusContract done
2023-04-25  Done2023-04-25
2023-05-15  Done2023-06-15
2024-01-032024-03-012024-04-05Delayed 
   Status missing 
2024-04-03  Progressing 
2024-06-03  Delayed 
2024-08-01  Progressing 

 

Variables

 

Actual

  • The cumulative sum of "Contract done" when the status column is "Done". 
  • It should only show up until Today's date 
  • In the above example, the cumulative sum today would be 2. 

Planned

  • The cumulative sum of "Contract scheduled done" 
  • It should only show from Today's date and forward 
  • In the above example, the cumulative sum would be 2 

Forecast

  • The cumulative sum of "Reschedule 2", "Reschedule 1" and "Contract scheduled done" 
  • Logic should be: If "Reschedule 2" contains data > pick this value. If "Reschedule 2" is emtpy > look at "Reschedule 1". If "Reschedule 1" contains data > pick this value. If "Reschedule 1" is emtpy > pick the value in "Contract scheduled done" 
  • Only from Today's date and forward 
3 ACCEPTED SOLUTIONS
Anonymous
Not applicable

Hi @carlenb ,

 

According to your description, here are my steps you can follow as a solution.

(1) We can create a calculated column.

Column = IF(ISBLANK('Table'[Reschedule 2]),IF(ISBLANK('Table'[Reschedule 1]),[Contract scheduled done],[Reschedule 1]),[Reschedule 2])

(2) We can create measures. 

Measure = 
var _Actual=CALCULATE(COUNT('Table'[Status]),FILTER(ALLSELECTED('Table'),'Table'[Status]="Done" && [Contract scheduled done]<=TODAY()))
var _Planned=CALCULATE(COUNT('Table'[Contract scheduled done]),FILTER(ALLSELECTED('Table'),[Contract scheduled done]>TODAY()))
RETURN IF(MAX('Calendar'[Date])<=TODAY(),_Actual,_Planned)
Measure 2 = 
var _Actual=CALCULATE(COUNT('Table'[Status]),FILTER(ALLSELECTED('Table'),'Table'[Status]="Done" && [Contract scheduled done]<=TODAY()))
var _Forecast=CALCULATE(COUNT('Table'[Column]),FILTER(ALLSELECTED('Table'),[Column]>TODAY()))
RETURN IF(MAX('Calendar'[Date])<=TODAY(),_Actual,_Forecast)

(3)Then the result is as follows.

vtangjiemsft_1-1711611925679.png

 

If the above one can't help you get the desired result, please provide your expected result with backend logic and special examples. Thank you.

 

Best Regards,

Neeko Tang

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

Anonymous
Not applicable

Hi @carlenb ,

 

We can create three measures.

Actual = 
var _max_date=CALCULATE(MAX('Table'[Contract done]),FILTER(ALL('Table'),[Status]="Done"))
var _Actual=CALCULATE(COUNT('Table'[Status]),FILTER(ALLSELECTED('Table'),'Table'[Status]="Done" && [Contract done]<=MAX('Calendar'[Date])))
RETURN IF(EOMONTH(MAX('Calendar'[Date]),0)<=EOMONTH(_max_date,0),_Actual,BLANK())
Planned = 
var _Planned=CALCULATE(COUNT('Table'[Status]),FILTER(ALLSELECTED('Table'),[Contract scheduled done]<=MAX('Calendar'[Date])))
RETURN _Planned
Forecast = 
var _max_date=CALCULATE(MAX('Table'[Contract done]),FILTER(ALL('Table'),[Status]="Done"))
var _Forecast=CALCULATE(COUNT('Table'[Column]),FILTER(ALLSELECTED('Table'),[Column]<=MAX('Calendar'[Date])))
RETURN IF(EOMONTH(MAX('Calendar'[Date]),0)>=EOMONTH(_max_date,0),_Forecast,BLANK())

vtangjiemsft_0-1711937977611.png

The x-axis places the date field of the date table. The date table cannot have duplicate dates.

There can be only one active relationship between the two tables. If you have more than one relationship between the date table and the fact table, you can use the USERELATIONSHIP() function to activate the inactive relationship.

 

 

Best Regards,

Neeko Tang

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

Anonymous
Not applicable

Hi @carlenb ,

 

Try them. You can create new measures.

New Actual Measure= CALCULATE (
            [Actual measure],
            USERELATIONSHIP ( FactTable[Date], 'Date'[Date] )
        )
New Planned Measure= CALCULATE (
            [Planned measure],
            USERELATIONSHIP ( FactTable[Date], 'Date'[Date] )
        )
New Forecast Measure= CALCULATE (
            [Forecast measure],
            USERELATIONSHIP ( FactTable[Date], 'Date'[Date] )
        )

Best Regards,

Neeko Tang

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

5 REPLIES 5
carlenb
Advocate II
Advocate II

Thanks a lot @Anonymous , I appreciate the help! I checked this for my use case and realized that there are some modifications needed. I increased the test data a bit (new link to model here) and created an output table and graph (Excel) below to better showcase the logic of the end result. 

 

Data set: 

Contract scheduled doneReschedule 1Reschedule 2StatusContract done
2023-04-25  Done2023-04-25
2023-05-15  Done2023-06-15
2024-01-032024-03-012024-06-05Delayed 
2024-02-032024-07-01 Delayed 
2024-03-01  Done2024-03-01
2024-04-03  Progressing 
2024-06-03  Delayed 
2024-08-01  Progressing 

 

Expected output based on data set: 

 

 ActualPlannedForecast
apr-2311 
maj-2312 
jun-2322 
aug-2322 
sep-2322 
okt-2322 
nov-2322 
dec-2322 
jan-2423 
feb-2424 
mar-24353
apr-24 64
maj-24 64
jun-24 75
jul-24 75
aug-24 86

 

End result (Excel graph):

 

carlenb_0-1711714820447.png

 

To specify each variable: 

 

Actual

  • Cumulative sum for when column "Status" is "Done"
  • No need to use TODAY() function here > can be removed 

 

Planned

  • Cumulative sum of "Contract schedule done"
  • No need to use TODAY() function here > can be removed 

 

Forecast

  • The calculated column will remain as the logic here is the same, except one change that it should start the cumulative Forecast count based on the latest "Actual" cumulative value. See example in the output table where "Actual" is 3 in March 2023 - this would be the starting value for Forecast

 

One more consideration is if USERELATIONSHIP should be used, given Calender will be used on the x-axis and there are multiple dates in Table? 

 

Appreciate your patience!

Anonymous
Not applicable

Hi @carlenb ,

 

We can create three measures.

Actual = 
var _max_date=CALCULATE(MAX('Table'[Contract done]),FILTER(ALL('Table'),[Status]="Done"))
var _Actual=CALCULATE(COUNT('Table'[Status]),FILTER(ALLSELECTED('Table'),'Table'[Status]="Done" && [Contract done]<=MAX('Calendar'[Date])))
RETURN IF(EOMONTH(MAX('Calendar'[Date]),0)<=EOMONTH(_max_date,0),_Actual,BLANK())
Planned = 
var _Planned=CALCULATE(COUNT('Table'[Status]),FILTER(ALLSELECTED('Table'),[Contract scheduled done]<=MAX('Calendar'[Date])))
RETURN _Planned
Forecast = 
var _max_date=CALCULATE(MAX('Table'[Contract done]),FILTER(ALL('Table'),[Status]="Done"))
var _Forecast=CALCULATE(COUNT('Table'[Column]),FILTER(ALLSELECTED('Table'),[Column]<=MAX('Calendar'[Date])))
RETURN IF(EOMONTH(MAX('Calendar'[Date]),0)>=EOMONTH(_max_date,0),_Forecast,BLANK())

vtangjiemsft_0-1711937977611.png

The x-axis places the date field of the date table. The date table cannot have duplicate dates.

There can be only one active relationship between the two tables. If you have more than one relationship between the date table and the fact table, you can use the USERELATIONSHIP() function to activate the inactive relationship.

 

 

Best Regards,

Neeko Tang

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

Thanks a lot @Anonymous. Could you help me adjust the measures to include USERELATIONSHIP? I've tried but can't quite get it right. 

 

Again, thanks for your support and patience! 

Anonymous
Not applicable

Hi @carlenb ,

 

Try them. You can create new measures.

New Actual Measure= CALCULATE (
            [Actual measure],
            USERELATIONSHIP ( FactTable[Date], 'Date'[Date] )
        )
New Planned Measure= CALCULATE (
            [Planned measure],
            USERELATIONSHIP ( FactTable[Date], 'Date'[Date] )
        )
New Forecast Measure= CALCULATE (
            [Forecast measure],
            USERELATIONSHIP ( FactTable[Date], 'Date'[Date] )
        )

Best Regards,

Neeko Tang

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

 

Anonymous
Not applicable

Hi @carlenb ,

 

According to your description, here are my steps you can follow as a solution.

(1) We can create a calculated column.

Column = IF(ISBLANK('Table'[Reschedule 2]),IF(ISBLANK('Table'[Reschedule 1]),[Contract scheduled done],[Reschedule 1]),[Reschedule 2])

(2) We can create measures. 

Measure = 
var _Actual=CALCULATE(COUNT('Table'[Status]),FILTER(ALLSELECTED('Table'),'Table'[Status]="Done" && [Contract scheduled done]<=TODAY()))
var _Planned=CALCULATE(COUNT('Table'[Contract scheduled done]),FILTER(ALLSELECTED('Table'),[Contract scheduled done]>TODAY()))
RETURN IF(MAX('Calendar'[Date])<=TODAY(),_Actual,_Planned)
Measure 2 = 
var _Actual=CALCULATE(COUNT('Table'[Status]),FILTER(ALLSELECTED('Table'),'Table'[Status]="Done" && [Contract scheduled done]<=TODAY()))
var _Forecast=CALCULATE(COUNT('Table'[Column]),FILTER(ALLSELECTED('Table'),[Column]>TODAY()))
RETURN IF(MAX('Calendar'[Date])<=TODAY(),_Actual,_Forecast)

(3)Then the result is as follows.

vtangjiemsft_1-1711611925679.png

 

If the above one can't help you get the desired result, please provide your expected result with backend logic and special examples. Thank you.

 

Best Regards,

Neeko Tang

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

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.