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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more

Reply
Anonymous
Not applicable

Measure for number of days between status updates

I have a Status_History table linked to a Proposal table by Proposal_ID. The Status_History table contains the Date and Status for each change. I want to create a measure that calculates the number of days between two specific statuses.

 

Status_History might look like this:

 

Screen Shot 2019-10-24 at 12.53.48 PM.png

 

 

I want to calculate the number of days between Recieved and Executed statuses and be able to filter across Proposal_ID depending on the context. I think I should use the DATESBETWEEN function, but I'm not sure how to get the dates for the statuses I'm interested in.

 

Ultimately, I'd like to get the average of this number for all proposals with Execution dates in a certain range (by quarter).

 

Thanks!

 

 

1 ACCEPTED SOLUTION

I am not sure if you were referring to measure as calculated column as that's what probably has caused the confusion. Anyway, try this as a calculated column: 

 

Diff =
VAR __RECEIVED =
    CALCULATE (
        MAX ( 'Table'[Created_On] ),
        ALLEXCEPT ( 'Table', 'Table'[Proposal_ID] ),
        'Table'[Status] = "Received"
    )
VAR __EXECUTED =
    CALCULATE (
        MAX ( 'Table'[Created_On] ),
        ALLEXCEPT ( 'Table', 'Table'[Proposal_ID] ),
        'Table'[Status] = "Executed"
    )
RETURN
    DATEDIFF ( __RECEIVED, __EXECUTED, DAY )

The result should look something like this:

2019-10-28 10_11_52-Window.png
Don't forget to change the names of the tables and column accordingly.

 





Dane Belarmino | Microsoft MVP | Proud to be a Super User!

Did I answer your question? Mark my post as a solution!


"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

View solution in original post

6 REPLIES 6
smpa01
Super User
Super User

Measure :=
DATEDIFF (
    CALCULATE (
        MAX ( T[Date] ),
        FILTER ( ALLEXCEPT ( T, T[ID] ), T[Status] = "Received" )
    ),
    CALCULATE (
        MAX ( T[Date] ),
        FILTER ( ALLEXCEPT ( T, T[ID] ), T[Status] = "Executed" )
    ),
    DAY
)

@Anonymousit might work

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
Anonymous
Not applicable

When I put the measure into a column of a matrix with Proposals records in the rows, it doesn't seem to filter based on Status_History[Proposal_ID]=Proposals[Proposal_ID]. I get the same result in every row. 

Hi @Anonymous ,

Tested @smpa01's formula and it worked just fine. You'll get the same figure for each row propsal ID as you're calculating the day difference between Received and Executed for each ID.
 2019-10-25 08_45_26-infographicDesigner.PBI_CV_73744D90_4DC9_4F18_8BA5_EE8FA5C98035.1.8.500.0 - Powe.png





Dane Belarmino | Microsoft MVP | Proud to be a Super User!

Did I answer your question? Mark my post as a solution!


"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.
Anonymous
Not applicable

I want columns in my table visual from the Proposal table and then a column with the measure, as such:

 

Screen Shot 2019-10-25 at 9.18.35 AM.png

 

Right now it looks like:

 

Screen Shot 2019-10-25 at 9.21.24 AM.png

 

Here's the code for Measure:

Measure = DATEDIFF (
   CALCULATE (
        MAX(proposal_status_history[created_on_date]),
        FILTER(ALLEXCEPT(proposal_status_history,proposal[proposal_id]),proposal_status_history[proposal_status]="Executed")
),
   CALCULATE (
      MAX (proposal_status_history[created_on_date]),
      FILTER(ALLEXCEPT(proposal_status_history,proposal[proposal_id]),proposal_status_history[proposal_status]="Awarded")
),
DAY
)

 

I am not sure if you were referring to measure as calculated column as that's what probably has caused the confusion. Anyway, try this as a calculated column: 

 

Diff =
VAR __RECEIVED =
    CALCULATE (
        MAX ( 'Table'[Created_On] ),
        ALLEXCEPT ( 'Table', 'Table'[Proposal_ID] ),
        'Table'[Status] = "Received"
    )
VAR __EXECUTED =
    CALCULATE (
        MAX ( 'Table'[Created_On] ),
        ALLEXCEPT ( 'Table', 'Table'[Proposal_ID] ),
        'Table'[Status] = "Executed"
    )
RETURN
    DATEDIFF ( __RECEIVED, __EXECUTED, DAY )

The result should look something like this:

2019-10-28 10_11_52-Window.png
Don't forget to change the names of the tables and column accordingly.

 





Dane Belarmino | Microsoft MVP | Proud to be a Super User!

Did I answer your question? Mark my post as a solution!


"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

@Anonymous  can you please show the desired output.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

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

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors