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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
jpt1228
Responsive Resident
Responsive Resident

Subtracting 2 dates results is too large on number of days

I am trying to calculate the % of days elapsed since the beginning of a custom fiscal 4 week period. I have a date table with date, week in year, fiscal week, is current week etc. In another post someone suggested adding a new column that would return the first day of the current fiscal period, but when I usethe datediff function it returns elapsed days such as 1,878 rather than 4-25-19 minus 4-20-19 = 5

 

https://community.powerbi.com/t5/Desktop/of-time-elapsed-in-custom-4-week-fiscal-period/m-p/690433#M...

 

first day per period =
CALCULATE ( MIN ( [Date] ), ALLEXCEPT ( 'Table', 'Table'[Fiscal period] ) )

 

date too many days.JPG

1 ACCEPTED SOLUTION

hi, @jpt1228 

"I think the problem is the IsCurrentFiscalPeriod repeats every year as True rather than just the current fiscal period in the current year."

This should be the reason for the problem, So just add a conditional in the formula:

Column =
IF (
    'Date'[IsCurrentFiscalPeriod] = TRUE ()
        && 'Date'[Year] = YEAR ( TODAY () ),
    DATEDIFF (
        CALCULATE (
            MIN ( 'Date'[Date Short] ),
            FILTER (
                'Date',
                'Date'[IsCurrentFiscalPeriod] = TRUE ()
                    && 'Date'[Year] = YEAR ( TODAY () )
            )
        ),
        'Date'[Date Short],
        DAY
    )
)

Best Regards,

Lin

 

Community Support Team _ Lin
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
v-lili6-msft
Community Support
Community Support

hi, @jpt1228 

What is your expected output?

datediff(3/23/2014 , today(), day) is right, why it should be 4-25-19 minus 4-20-19 = 5

I didn't see 4-25-19 or 4-20-19 in the screenshot.

 

Best Regards,

Lin

 

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

Hi @v-lili6-msft I was using those 2 dates as an example. Given the below date table it appears that the fiscal period start date is correct for the month/day but incorrect for the year. I would like the Date Short highlighted 5-23-19 to show how many days have elapsed since the first day of the fiscal period which started on 5-19-19.

 

5-23-19 minus 5-19-19 = 4. On 5-24-19 the calculation would be 5-24-19 minus 5-19-19 = 5. 

 

date table fiscal.JPG

hi, @jpt1228 

Sorry for the late reply, Try this formula to create a column

Column = IF('Date'[IsCurrentFiscalPeriod]=TRUE(),DATEDIFF(CALCULATE(MIN('Date'[Date Short]),FILTER('Date','Date'[IsCurrentFiscalPeriod]=TRUE())),'Date'[Date Short],DAY))

OR

Column 2 = IF('Date'[IsCurrentFiscalPeriod]=TRUE()&&'Date'[Date Short]>=TODAY(),DATEDIFF(CALCULATE(MIN('Date'[Date Short]),FILTER('Date','Date'[IsCurrentFiscalPeriod]=TRUE())),'Date'[Date Short],DAY))

Result:

7.JPG

 

Best Regards,

Lin

 

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

Hello @v-lili6-msft  - I created a column as suggested but not getting the desired result. The Min date in the table starts in year 2014. 

 

I think the problem is the IsCurrentFiscalPeriod repeats every year as True rather than just the current fiscal period in the current year.

 

the column formula for IsCurrentFiscalPeriod is:

 

IsCurrentFiscalPeriod =
VAR TodaysPeriod = MINX(FILTER(DimDate, DimDate[Date] =
TODAY()), DimDate[FLO Fiscal Period])
RETURN
IF(dimdate[FLO Fiscal Period] = TodaysPeriod, TRUE(), FALSE())

 

DimDateTEST.JPG

hi, @jpt1228 

"I think the problem is the IsCurrentFiscalPeriod repeats every year as True rather than just the current fiscal period in the current year."

This should be the reason for the problem, So just add a conditional in the formula:

Column =
IF (
    'Date'[IsCurrentFiscalPeriod] = TRUE ()
        && 'Date'[Year] = YEAR ( TODAY () ),
    DATEDIFF (
        CALCULATE (
            MIN ( 'Date'[Date Short] ),
            FILTER (
                'Date',
                'Date'[IsCurrentFiscalPeriod] = TRUE ()
                    && 'Date'[Year] = YEAR ( TODAY () )
            )
        ),
        'Date'[Date Short],
        DAY
    )
)

Best Regards,

Lin

 

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

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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