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

Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM. Register now.

Reply
Anonymous
Not applicable

Count rows with datediff previous date and actual date between 30 days

I have this kind of data table with DeviceNr, TaskNr and date:

 

DeviceNrTaskNrDate
D001T-00101.01.2020
D001T-00102.01.2020
D001T-00225.01.2020
D001T-00327.01.2020
D001T-00330.01.2020
D002T-00405.01.2020
D002T-00503.02.2020
D002T-00607.02.2020
D002T-00610.03.2020
D002T-00713.03.2020
D002T-00817.04.2020
D003T-00905.01.2020
D003T-01008.02.2020
D003T-01010.02.2020
D003T-01114.02.2020


I want to get this result:

Friedrich_0-1617779244922.png

 

 

The result measure should count the rows with the condition: "if the datediff between the previous average date an the actual average date is <= 30 days it should count the row."

 

The average date is calculated in the data model with:

=AVERAGEX(FILTER('tab_tasks';'tab_tasks'[TaskNr]=EARLIER('tab_tasks'[TaskNr]));'tab_tasks'[Date])


The previous date is calculated with:

=CALCULATE(MAX('tab_tasks'[average date per task]);FILTER(ALL(tab_tasks[TaskNr];'tab_tasks'[average date per task]);COUNTROWS(FILTER('tab_tasks';EARLIER(tab_tasks[average date per task])<'tab_tasks'[average date per task]))))

1 ACCEPTED SOLUTION

 

Average Date = CALCULATE(average(tab_tasks[Date]),ALLEXCEPT(tab_tasks,tab_tasks[TaskNr],tab_tasks[DeviceNr]))

Prev Avg Date = 
var t = tab_tasks[TaskNr]
var pt = CALCULATE(max(tab_tasks[TaskNr]),ALLEXCEPT(tab_tasks,tab_tasks[DeviceNr]),tab_tasks[TaskNr]<t)
return CALCULATE(AVERAGE(tab_tasks[Date]),ALLEXCEPT(tab_tasks,tab_tasks[DeviceNr]),tab_tasks[TaskNr]=pt)

Ct = 
var c = CALCULATE(COUNTROWS(tab_tasks),ALLEXCEPT(tab_tasks,tab_tasks[DeviceNr],tab_tasks[TaskNr]))
return SWITCH(TRUE(),ISBLANK(tab_tasks[Prev Avg Date]),BLANK(),datediff(tab_tasks[Prev Avg Date],tab_tasks[Average Date],DAY)<31,divide(1,c,0),0)

 

 

lbendlin_0-1618499430370.png

 

View solution in original post

7 REPLIES 7
lbendlin
Super User
Super User

See my reply above. I already used your new sample data.

lbendlin
Super User
Super User

Please provide sample data that covers such a scenario.

Anonymous
Not applicable

Thank you for your reply. In the following table is the new example date for the table 'tab_tasks'

There are some issues with the HTML Code for tables.

 

DeviceNr TaskNr Date
D001 T-0CE 01.01.2020 00:00:00
D001 T-0CE 02.01.2020 00:00:00
D001 T-0WB 25.01.2020 00:00:00
D001 T-0CR 27.01.2020 00:00:00
D001 T-0CR 30.01.2020 00:00:00
D002 T-0VW 05.01.2020 00:00:00
D002 T-0BM 03.02.2020 00:00:00
D002 T-0WY 07.02.2020 00:00:00
D002 T-0WY 10.03.2020 00:00:00
D002 T-0LL 13.03.2020 00:00:00
D002 T-0UU 17.04.2020 00:00:00
D003 T-0EW 05.01.2020 00:00:00
D003 T-0IU 08.02.2020 00:00:00
D003 T-0IU 10.02.2020 00:00:00
D003 T-0PT 14.02.2020 00:00:00

Anonymous
Not applicable

Thank you for your reply. In the following table is the new example date for the table 'tab_tasks'

 

DeviceNrTaskNrDateD001T-0CE01.01.2020D001T-0CE02.01.2020D001T-0WB25.01.2020D001T-0CR27.01.2020D001T-0CR30.01.2020D002T-0VW05.01.2020D002T-0BM03.02.2020D002T-0WY07.02.2020D002T-0WY10.03.2020D002T-0LL13.03.2020D002T-0UU17.04.2020D003T-0EW05.01.2020D003T-0IU08.02.2020D003T-0IU10.02.2020D003T-0PT14.02.2020

 

Average Date = CALCULATE(average(tab_tasks[Date]),ALLEXCEPT(tab_tasks,tab_tasks[TaskNr],tab_tasks[DeviceNr]))

Prev Avg Date = 
var t = tab_tasks[TaskNr]
var pt = CALCULATE(max(tab_tasks[TaskNr]),ALLEXCEPT(tab_tasks,tab_tasks[DeviceNr]),tab_tasks[TaskNr]<t)
return CALCULATE(AVERAGE(tab_tasks[Date]),ALLEXCEPT(tab_tasks,tab_tasks[DeviceNr]),tab_tasks[TaskNr]=pt)

Ct = 
var c = CALCULATE(COUNTROWS(tab_tasks),ALLEXCEPT(tab_tasks,tab_tasks[DeviceNr],tab_tasks[TaskNr]))
return SWITCH(TRUE(),ISBLANK(tab_tasks[Prev Avg Date]),BLANK(),datediff(tab_tasks[Prev Avg Date],tab_tasks[Average Date],DAY)<31,divide(1,c,0),0)

 

 

lbendlin_0-1618499430370.png

 

Anonymous
Not applicable

Hello, thank you for your reply. 
It is very important, that the subtotals will be calculated right, as the sum of the column ct.
If I want to copy your measure "Prev Avg Date", I get an error message: "Not a single value can be determined for column TaskNr".
Maybe there is another solution approach.
Best regards

lbendlin
Super User
Super User

Note: the below are calculated columns as you didn't indicate if the result can be impacted by user filter choices and you didn't indicate what to do with the DeviceNr.

 

 

 

Average Date = CALCULATE(average(tab_tasks[Date]),ALLEXCEPT(tab_tasks,tab_tasks[TaskNr]))

Prev Avg Date = 
var t = tab_tasks[TaskNr]
var pt = CALCULATE(max(tab_tasks[TaskNr]),ALL(tab_tasks),tab_tasks[TaskNr]<t)
return CALCULATE(AVERAGE(tab_tasks[Date]),ALL(tab_tasks),tab_tasks[TaskNr]=pt)

Ct = if(datediff(tab_tasks[Prev Avg Date],tab_tasks[Average Date],DAY)<31,1,0)

 

 

 

I leave the cleanup decisions up to you.  Technically a single date per task can still  yield an average.

lbendlin_0-1618448814359.png

 

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.