cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Martin_Bruwer Frequent Visitor
Frequent Visitor

Calculate difference between rows

Hello All,

 

I'm trying to calculate the number of days between two appointments where the first appointment could be one of two types. in the below table it would be the days between the earlier of appointment type one or two and appointment three.

 

Patient IDAppointment TypeAppintment Date
112233Type 101/10/2017
112233Type 201/11/2017
112233Type 301/01/2018
223344Type 101/10/2017
223344Type 201/09/2017
223344Type 301/01/2018

 

For for example patient 112233, would be days between appointment type 1 (being the earlier of appointment 1 and 2) and appointment type 3, so 61 days.

 

I am thinking a calculated column which returns the earliest date of the two filtered by patient ID and then just a datediff between the two dates on the row with appointment type 3.

 

Any thoughts?

 

Martin

1 ACCEPTED SOLUTION

Accepted Solutions
Super User
Super User

Re: Calculate difference between rows

@Martin_Bruwer

 

Measure =
VAR EarlierAppointment =
    CALCULATE (
        MIN ( TableName[Appintment Date] ),
        FILTER (
            ALLEXCEPT ( TableName, TableName[Patient ID] ),
            TableName[Appointment Type] = "Type 1"
                || TableName[Appointment Type] = "Type 2"
        )
    )
VAR Type3Date =
    CALCULATE (
        FIRSTNONBLANK ( TableName[Appintment Date], 1 ),
        FILTER (
            ALLEXCEPT ( TableName, TableName[Patient ID] ),
            TableName[Appointment Type] = "Type 3"
        )
    )
VAR Start_date =
    MIN ( EarlierAppointment, Type3Date )
VAR End_date =
    MAX ( EarlierAppointment, Type3Date )
RETURN
    DATEDIFF ( Start_date, End_date, DAY )

View solution in original post

7 REPLIES 7
Super User
Super User

Re: Calculate difference between rows

Hi @Martin_Bruwer

 

Try this calculated column

 

Column =
VAR EarlierAppointment =
    CALCULATE (
        MIN ( TableName[Appintment Date] ),
        FILTER (
            ALLEXCEPT ( TableName, TableName[Patient ID] ),
            TableName[Appointment Type] = "Type 1"
                || TableName[Appointment Type] = "Type 2"
        )
    )
VAR Type3Date =
    CALCULATE (
        FIRSTNONBLANK ( TableName[Appintment Date], 1 ),
        FILTER (
            ALLEXCEPT ( TableName, TableName[Patient ID] ),
            TableName[Appointment Type] = "Type 3"
        )
    )
RETURN
    DATEDIFF ( EarlierAppointment, Type3Date, DAY )
Super User
Super User

Re: Calculate difference between rows

@Martin_Bruwer

 

Hopefully This formula will work as a MEASURE as well

ChrisHaas Established Member
Established Member

Re: Calculate difference between rows

Depends on if you need the values as a column, or if a measure would suffice (measures are preferred from a performance standpoint).

 

Try this measure:

[Measure] =
VAR CurrentPatient =
    VALUES ( TableName[Patient ID] )
VAR Appointment3Date =
    CALCULATE (
        MIN ( TableName[Appointment Date] ),
        TableName[Appointment Type] = "Type 3",
        TableName[Patient ID] IN CurrentPatient
    )
VAR EarliestAppointmentDate =
    CALCULATE (
        MIN ( TableName[Appointment Date] ),
        TableName[Appointment Type] IN { "Type 1", "Type 2" },
        TableName[Patient ID] IN CurrentPatient
    )
RETURN
    Appointment3Date - EarliestAppointmentDate

Variables make it easy to call out what each part of the calculation is doing.

Martin_Bruwer Frequent Visitor
Frequent Visitor

Re: Calculate difference between rows

Thank you @Zubair_Muhammad and @ChrisHaas

 

Chris,

 

I used your measure but made a slight change to the return,

 

Changed your to

 

  DATEDIFF(EarliestAppointmentDate,AppointmentDate,day)

 

Giving me days as opposed to a date formate.

 

It appears to be working, time to do testing.

 

Thank you so much.

Martin_Bruwer Frequent Visitor
Frequent Visitor

Re: Calculate difference between rows

@ChrisHaas

 

Hi Again,

 

Immidiately ran into two issues.

 

  1. Because of the nature of the business it is possible to have a patient who has appointment type 3 prior to appointment types 1 or 2. Using Datediff I get the error that the start date cannot be greater than the end date.  I could not use datediff but I need to have a result in days rather than a date.
  2. The result is also needed to be and Median and Mean over many hundreds of patients, with the measure I'm not sure where to put the function in.

 

Thank you again.

 

Martin

Super User
Super User

Re: Calculate difference between rows

@Martin_Bruwer

 

Measure =
VAR EarlierAppointment =
    CALCULATE (
        MIN ( TableName[Appintment Date] ),
        FILTER (
            ALLEXCEPT ( TableName, TableName[Patient ID] ),
            TableName[Appointment Type] = "Type 1"
                || TableName[Appointment Type] = "Type 2"
        )
    )
VAR Type3Date =
    CALCULATE (
        FIRSTNONBLANK ( TableName[Appintment Date], 1 ),
        FILTER (
            ALLEXCEPT ( TableName, TableName[Patient ID] ),
            TableName[Appointment Type] = "Type 3"
        )
    )
VAR Start_date =
    MIN ( EarlierAppointment, Type3Date )
VAR End_date =
    MAX ( EarlierAppointment, Type3Date )
RETURN
    DATEDIFF ( Start_date, End_date, DAY )

View solution in original post

Martin_Bruwer Frequent Visitor
Frequent Visitor

Re: Calculate difference between rows

Thank you very much, I believe I have a solution now. Trial and error.

 

 

Helpful resources

Announcements
Can You Solve These Challenge

Challenge: Can You Solve These?

Find out how to participate in the first Power BI 'Can You Solve These?' challenge.

New Badges

Incoming: New and Improved Badges

Exciting news: We've given our badges an overhaul and added brand news ones.

Ask Amir Anything

Exclusive LIVE Community Event No. 2 – Ask Amir Anything

Next in our Triple A series: Ask Amir Netz questions about the latest updates, features and future.

Analytics in Azure virtual event

Analytics in Azure virtual event

Experience a limitless analytics service built to ingest, prep, manage, and serve data for immediate use in Power BI.

Users Online
Currently online: 312 members 3,037 guests
Please welcome our newest community members: