cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
magnificentnile
Regular Visitor

Date Diff Question using IF and ISBLANK

I have 2 columns

one vRTT[DateInPublishing 

vRTT[DateOutOfPublishing]

 

If vRTT[DateOutOfPublishing] ISBLANK I would like DateDiff to calculate based on TODAY() otherwise it would calculate the datediff between the In and Out fields. 

 

I thought something like the following woud work...

 

WIPLayout = DATEDIFF(vRTT[DateInPublishing],
(IF(ISBLANK(vRTT[DateOutOfPublishing]), TODAY(), vRTT[DateOutOfPublishing])),
vRTT[DateOutOfPublishing],DAY)

1 ACCEPTED SOLUTION

Okay I think we got this - test it to make sure Smiley Happy

 

WIPLayout =
IF (
    ISBLANK ( vRTT[DateOutOfPublishing] ),
    SWITCH (
        TRUE (),
        TODAY () > vRTT[DateInPublishing], DATEDIFF ( vRTT[DateInPublishing], TODAY (), DAY ),
        TODAY () < vRTT[DateInPublishing], DATEDIFF ( TODAY (), vRTT[DateInPublishing], DAY ) * -1,
        0
    ),
    SWITCH (
        TRUE (),
        vRTT[DateOutOfPublishing] > vRTT[DateInPublishing], DATEDIFF ( vRTT[DateInPublishing], vRTT[DateOutOfPublishing], DAY ),
        vRTT[DateOutOfPublishing] < vRTT[DateInPublishing], DATEDIFF ( vRTT[DateOutOfPublishing], vRTT[DateInPublishing], DAY ) * -1,
        0
    )
)

 

EDIT:

So if the "OutOf" or "published" date is blank

The first SWITCH checks whether the "In" or "submitted" date is so to speak in the future i.e. > today

this is what throws off the error (those results will be negative * -1)

 

The second SWITCH checks whether it could have been "published" before it was ever "submitted"

again those results will be negative

 

Hope this makes sense!

View solution in original post

4 REPLIES 4
Sean
Community Champion
Community Champion

WIPLayout =
IF (
    ISBLANK ( vRTT[DateOutOfPublishing] ),
    DATEDIFF ( vRTT[DateInPublishing], TODAY (), DAY ),
    DATEDIFF ( vRTT[DateInPublishing], vRTT[DateOutOfPublishing], DAY )
)

Supplental question:

 

WIPapproval = DATEDIFF(vRTT[DateOutOfPublishing], (IF(ISBLANK(vRTT[PublishedDate]), TODAY(), vRTT[PublishedDate])), DAY) 

 

returns an error:

In DATEDIFF function, the start date cannot be greater than the end date

 

How would I put an IF statement in front to capture the situations where the DATEDIFF throws the error?

Okay I think we got this - test it to make sure Smiley Happy

 

WIPLayout =
IF (
    ISBLANK ( vRTT[DateOutOfPublishing] ),
    SWITCH (
        TRUE (),
        TODAY () > vRTT[DateInPublishing], DATEDIFF ( vRTT[DateInPublishing], TODAY (), DAY ),
        TODAY () < vRTT[DateInPublishing], DATEDIFF ( TODAY (), vRTT[DateInPublishing], DAY ) * -1,
        0
    ),
    SWITCH (
        TRUE (),
        vRTT[DateOutOfPublishing] > vRTT[DateInPublishing], DATEDIFF ( vRTT[DateInPublishing], vRTT[DateOutOfPublishing], DAY ),
        vRTT[DateOutOfPublishing] < vRTT[DateInPublishing], DATEDIFF ( vRTT[DateOutOfPublishing], vRTT[DateInPublishing], DAY ) * -1,
        0
    )
)

 

EDIT:

So if the "OutOf" or "published" date is blank

The first SWITCH checks whether the "In" or "submitted" date is so to speak in the future i.e. > today

this is what throws off the error (those results will be negative * -1)

 

The second SWITCH checks whether it could have been "published" before it was ever "submitted"

again those results will be negative

 

Hope this makes sense!

Thank you very much!

Helpful resources

Announcements
Carousel_PBI_Wave1

2023 Release Wave 1 Plans

Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.

Power BI Summit Carousel 2

Global Power BI Training

Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!

BizApps LATAM 2023

Business Application LATAM Summit 2023

Join the biggest FREE Business Applications Event in LATAM this February.

Power Platform Bootcamp

Global Power Platform Bootcamp

In this bootcamp we will deep-dive into Microsoft’s Power Platform stack with hands-on sessions and labs, delivered to you by experts and community leaders.