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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
Anonymous
Not applicable

Aggregate rows only if datetime is consecutive

Hello! I am trying to do something with PowerBI and can't find the correct way of doing it.

The idea is the following, I have a table similar to this:

 

Location

Start DateTimeEnd DateTimeType
A10/10 01:00    10/10 02:00    a
A10/10 02:00    10/10 03:00    a
A10/10 03:00    10/10 04:00    a
A10/10 08:00    10/10 09:00    a
A10/10 10:00    10/10 11:00    b
A10/10 11:00    10/10 12:00    b
B10/10 01:00     10/10 02:00    a
B10/10 04:00    10/10 05:00    b
B10/10 05:0010/10 06:00    b
B10/10 07:00    10/10 08:00    

a

 

All the time durations are of 1h. 

What I want to achieve is to aggregate the rows where datetimes are consecutive (and location and type are the same), and get something like this:

LocationStart DateTimeEnd DateTimeType
A10/10 01:00    10/10 04:00    a
A10/10 08:00    10/10 09:00    a
A10/10 10:0010/10 12:00b
B10/10 01:0010/10 02:00a
B10/10 04:0010/10 06:00b
B10/10 07:0010/10 08:00a

 

Any idea? 

Thank you!!

 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Anonymous ,

 

Please follow these steps.

1. Add a Index column

2. Create measures:

Rank = RANKX (FILTER(ALL ('Table'), [Location] = MAX ('Table'[Location]) && [Type]=MAX('Table'[Type])),CALCULATE (MAX(('Table'[Start DateTime]))),,ASC)


Flag = 
var _next= CALCULATE(MAX('Table'[Start DateTime]),FILTER(ALL('Table'),[Location]=MAX('Table'[Location]) && [Type]=MAX('Table'[Type]) && [Rank]=MAXX('Table',[Rank])+1))
var _pre= CALCULATE(MAX('Table'[Start DateTime]),FILTER(ALL('Table'),[Location]=MAX('Table'[Location]) && [Type]=MAX('Table'[Type]) && [Rank]=MAXX('Table',[Rank])-1))
var _diff1=DATEDIFF(_pre, MAX('Table'[Start DateTime]),HOUR)
var _diff2=DATEDIFF(MAX('Table'[Start DateTime]),_next,HOUR)
return IF(_diff2=1 || _diff1=1 ,1,0)


Start = IF([Flag]=1, MINX(FILTER(ALL('Table'),[Location]=MAX('Table'[Location]) && [Type]=MAX('Table'[Type]) &&[Flag]=1),[Start DateTime]),MAX('Table'[Start DateTime]))


End = IF([Flag]=1, MAXX(FILTER(ALL('Table'),[Location]=MAX('Table'[Location]) && [Type]=MAX('Table'[Type]) &&[Flag]=1),[End DateTime]),MAX('Table'[End DateTime]))

Output:

Eyelyn9_0-1656918661320.png

3.Then create a measure for visual-level filter to keep distinct rows:

For filter = IF(MAX('Table'[Start DateTime])=[Start],1,0)

Final output:

Eyelyn9_1-1656918720680.png

 

Best Regards,
Eyelyn Qin
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

2 REPLIES 2
Anonymous
Not applicable

Hi @Anonymous ,

 

Please follow these steps.

1. Add a Index column

2. Create measures:

Rank = RANKX (FILTER(ALL ('Table'), [Location] = MAX ('Table'[Location]) && [Type]=MAX('Table'[Type])),CALCULATE (MAX(('Table'[Start DateTime]))),,ASC)


Flag = 
var _next= CALCULATE(MAX('Table'[Start DateTime]),FILTER(ALL('Table'),[Location]=MAX('Table'[Location]) && [Type]=MAX('Table'[Type]) && [Rank]=MAXX('Table',[Rank])+1))
var _pre= CALCULATE(MAX('Table'[Start DateTime]),FILTER(ALL('Table'),[Location]=MAX('Table'[Location]) && [Type]=MAX('Table'[Type]) && [Rank]=MAXX('Table',[Rank])-1))
var _diff1=DATEDIFF(_pre, MAX('Table'[Start DateTime]),HOUR)
var _diff2=DATEDIFF(MAX('Table'[Start DateTime]),_next,HOUR)
return IF(_diff2=1 || _diff1=1 ,1,0)


Start = IF([Flag]=1, MINX(FILTER(ALL('Table'),[Location]=MAX('Table'[Location]) && [Type]=MAX('Table'[Type]) &&[Flag]=1),[Start DateTime]),MAX('Table'[Start DateTime]))


End = IF([Flag]=1, MAXX(FILTER(ALL('Table'),[Location]=MAX('Table'[Location]) && [Type]=MAX('Table'[Type]) &&[Flag]=1),[End DateTime]),MAX('Table'[End DateTime]))

Output:

Eyelyn9_0-1656918661320.png

3.Then create a measure for visual-level filter to keep distinct rows:

For filter = IF(MAX('Table'[Start DateTime])=[Start],1,0)

Final output:

Eyelyn9_1-1656918720680.png

 

Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Make sure to sort before grouping, then add the GroupKind.Local parameter to the end of your group step.

 

--Nate

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.

Top Kudoed Authors