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
Anonymous
Not applicable

Calculate date difference for a specific column value+ exclude values

Hello all, 

I'm stuck with some calculation and I could use some help. 

Here's what I'm trying to do :  I have a production table with all my production orders and I would like to calculate the average duration between campaign for each specific group of product (then I'll be able to calculate the stock recommandation based on the average lenght of replenishment). 

Here's an example of my dataset : 

ProductDateProduct Group
BB05-09-18Group B
BB06-09-18Group B
AA13-09-18Group A
BB22-09-18Group B
AA29-09-18Group A
BB01-10-18Group B
BA01-10-18Group B
BB11-10-18Group B
AA15-10-18Group A
AC16-10-18Group A
AA20-10-18Group A
AC21-10-18Group A
BB24-10-18Group B
BA26-10-18Group B
AA01-11-18Group A
AA03-11-18Group A
AC03-11-18Group A
AB04-11-18Group A
AA04-11-18Group A
AA05-11-18Group A
AA09-11-18Group A
AA11-11-18Group A
BB20-11-18Group B
AA06-12-18Group A
BB07-12-18Group B
AB08-12-18Group A
AC09-12-18Group A
AA09-12-18Group A
BB11-12-18Group B
BA14-12-18Group B
AC23-12-18Group A
AA05-01-19Group A
AA06-01-19Group A
BB08-01-19Group B
BB08-01-19Group B
AA22-01-19Group A
BB23-01-19Group B
BA24-01-19Group B
BB24-01-19Group B
AA06-02-19Group A
AA07-02-19Group A
BB12-02-19Group B
BB22-02-19Group B
BB26-02-19Group B
AA11-03-19Group A
AC11-03-19Group A
BB12-03-19Group B
BB18-03-19Group B
BA22-03-19Group B
CA09-02-19Group C
CB10-12-18Group C
CC24-10-18Group C
CB11-09-18Group C
CC11-09-18Group C
CC13-08-18Group C
CB05-07-18Group C
CB21-04-18Group C
CB26-01-18Group C
CA11-09-18Group C
CA05-07-18Group C
CA21-04-18Group C
CA16-01-18Group C
CA26-01-18Group C
CC22-05-18Group C
CC05-07-18Group C
CC21-04-18Group C
CC17-01-18Group C
CC25-01-18Group C

 

What I would like to calculate is first the difference between two campaign then the average duration between campaign for each Product Group. 

 

From a previous thread I found the following formula for a calculated table : 

DaysBetween =
DATEDIFF (
    'Table'[date],
    FIRSTDATE (
        FILTER ( ALL ( 'Table'[DATE] ), 'Table'[DATE] > EARLIER ( 'Table'[DATE] ) )
    ),
    DAY
)
However this will give me the date difference between each production orders and not the product group. 

Additionnaly to this, I would like to be able to exclude some values from my calculation. Because my table is made from all the production orders, it doesn't reflect exactly the horizon of each campaign. During a production campaign, I'll have several production orders over several days (which will then give me a couple of 1 day interval based on my table) and my goal is to calculate the duration between campaign, not during each production orders. 

Let me know if it's clear and thanks a lot for your help. 
KyloRen

 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Ok thank you for your reply, I manage to get the measure I expected from that topic. 

So the first calculated column gives me the date of the last production for each product group row : 

Date_Previous_Campaign = 
MAXX (
    TOPN (
        1;
        FILTER (
            TABLE;
           TABLE[Product Group] = EARLIER ( TABLE[Product Group] )
                && TABLE[DATE] < EARLIER ( TABLE[DATE] )
        );
       TABLE[DATE]; DESC
    );
    TABLE[DATE]
)

Then I create a second calculated column to calculate the duration between two production orders : 

Days since last campaign = DATEDIFF(TABLE[Date_Previous_Campaign];TABLE[DATE];DAY)


Then eventually my measure of average, excluding values under 3 days to really focus on campaign : 

Average Duration = CALCULATE(AVERAGE(TABLE[Days since last campaign]);TABLE[Days since last campaign]>3)


Thanks for your answer, I got the result I expected. However it might not be the most optimized solution. 

Have a good day !

View solution in original post

2 REPLIES 2
v-chuncz-msft
Community Support
Community Support

@Anonymous ,

 

You may check if the post below helps.

https://community.powerbi.com/t5/Desktop/Finding-the-previos-occurrence-within-same-table-based-on-one/m-p/342607#M153516

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

Ok thank you for your reply, I manage to get the measure I expected from that topic. 

So the first calculated column gives me the date of the last production for each product group row : 

Date_Previous_Campaign = 
MAXX (
    TOPN (
        1;
        FILTER (
            TABLE;
           TABLE[Product Group] = EARLIER ( TABLE[Product Group] )
                && TABLE[DATE] < EARLIER ( TABLE[DATE] )
        );
       TABLE[DATE]; DESC
    );
    TABLE[DATE]
)

Then I create a second calculated column to calculate the duration between two production orders : 

Days since last campaign = DATEDIFF(TABLE[Date_Previous_Campaign];TABLE[DATE];DAY)


Then eventually my measure of average, excluding values under 3 days to really focus on campaign : 

Average Duration = CALCULATE(AVERAGE(TABLE[Days since last campaign]);TABLE[Days since last campaign]>3)


Thanks for your answer, I got the result I expected. However it might not be the most optimized solution. 

Have a good day !

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.