cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
roelf Helper I
Helper I

Calculate days between 2 events in inspection records

Hi Experts

 

I need to calculate the days between 2 events. It relates vehicles, and inspections are done weekly, but the vehicles are only sometimes serviced. When a vehicle is serviced, i need to calculate the days since it's last service.

 

My data looks as follows:

 

Vehicle   Date Inspected    Serviced    Days since previous service

  A           date 1                   Y              

  B           date 2                   N  

  A           date 3                   N

  B           date 4                   N

  A           date 5                   Y             date 5 - date 1

  B           date 6                  N

  A           date 7                  Y              date 7 - date 5

 

Now the DATEDIFF part is no problem. My problem is knowing how to find the PREVIOUS date serviced, for the vehicle.

 

My formula for trying to find the previous date currently looks like this:

 

Prev Service Date = 

     CALCULATE (

            MIN (table [Date Inspected] ),

            ALLEXCEPT (Table, Table[Vehicle]),

            FILTER (Table, Table[Date Inspected] <= Table[Date Inspected] && Table[Serviced]="Y"))

 

I do not get an error... but I get the same value for all the rows in the table

 

Any help will be much appreciated

 

 

 

 

 

1 ACCEPTED SOLUTION

Accepted Solutions
Vvelarde Community Champion
Community Champion

Re: Calculate days between 2 events in inspection records

@roelf

 

 

Hi, try with this calculated column:

 

Days since Prev Service =
VAR DateInspected = Tabla1[Date Inspected]
VAR PreviosDay =
    CALCULATE (
        MAX ( Tabla1[Date Inspected] ),
        FILTER (
            Tabla1,
            Tabla1[Date Inspected] < DateInspected
                && Tabla1[Vehicle] = EARLIER ( Tabla1[Vehicle] )
                && Tabla1[Serviced] = "Y"
        )
    )
RETURN
    IF ( Tabla1[Serviced] = "Y", DATEDIFF ( PreviosDay, DateInspected, DAY ) )

Regards

 

Victor




Lima - Peru

View solution in original post

5 REPLIES 5
Vvelarde Community Champion
Community Champion

Re: Calculate days between 2 events in inspection records

@roelf

 

 

Hi, try with this calculated column:

 

Days since Prev Service =
VAR DateInspected = Tabla1[Date Inspected]
VAR PreviosDay =
    CALCULATE (
        MAX ( Tabla1[Date Inspected] ),
        FILTER (
            Tabla1,
            Tabla1[Date Inspected] < DateInspected
                && Tabla1[Vehicle] = EARLIER ( Tabla1[Vehicle] )
                && Tabla1[Serviced] = "Y"
        )
    )
RETURN
    IF ( Tabla1[Serviced] = "Y", DATEDIFF ( PreviosDay, DateInspected, DAY ) )

Regards

 

Victor




Lima - Peru

View solution in original post

roelf Helper I
Helper I

Re: Calculate days between 2 events in inspection records

Thanks a lot !!

 

If you don't mind - won't you explain the use of "earlier" in the formula ?

 

I do not understand what "earlier" does... I have read somewhere using earlier is quite resource intensive?

 

Thanks again - works very well

Vvelarde Community Champion
Community Champion

Re: Calculate days between 2 events in inspection records

@roelf

 

The EARLIER function take the value of the field before apply the formula context.

 

You can use a VAR to replace the EARLIER.

 

Regards

 

Victor




Lima - Peru
roelf Helper I
Helper I

Re: Calculate days between 2 events in inspection records

Thanks for the reply.

 

Do I understand correctly that you mean do this :

 

Days since Prev Service =
VAR DateInspected = Tabla1[Date Inspected]
VAR PreviosVeh = Tabla1[Vehicle] VAR PreviosDay = CALCULATE ( MAX ( Tabla1[Date Inspected] ), FILTER ( Tabla1, Tabla1[Date Inspected] < DateInspected && Tabla1[Vehicle] = PreviosVeh ) && Tabla1[Serviced] = "Y" ) ) RETURN IF ( Tabla1[Serviced] = "Y", DATEDIFF ( PreviosDay, DateInspected, DAY ) )

 

If I do this - will this use less resource ?

 

Thanks

Roelf

Highlighted
Vvelarde Community Champion
Community Champion

Re: Calculate days between 2 events in inspection records

@roelf

 

Is more legible and understable to EARLIER.

 

The VAR use less resource when you use it more than 1 time in the DAX Formula.

 

 

 

 




Lima - Peru

Helpful resources

Announcements
Announcing the New Spanish Forum

Announcing the New Spanish Forum

Do you need help in Spanish? Check out our new Spanish community section.

April 2020 Community Highlights

April 2020 Community Highlights

Info on our Super Users, MBAS content and badges, and updates to our support articles. - Read the full Community Highlights.

MBAS Gallery 2020

MBAS Gallery 2020

Watch Microsoft Business Applications Summit sessions on-demand.

Top Solution Authors
Top Kudoed Authors