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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
emmabrice
Frequent Visitor

Group by with gaps in data

Hi 


I cant think of a way to do this and hoping you can help.

 

I have data that looks like this 

 

PersonIDEffective DateEnd DateJob Title
214520/02/201730/04/2017Job 1
214501/05/201714/09/2017Job 1
214515/09/201701/10/2017Job 1
214502/10/201711/01/2018Job 1
214512/01/201831/07/2018Job 1
214501/08/201814/09/2018Job 1
214515/09/201814/09/2019Job 1
214515/09/201904/10/2020Job 1
214505/10/202018/04/2021Job 2
214519/04/202120/05/2021Job 1
214521/05/202131/12/2222Job 1

 

I want to get it looking like this

 

PersonIDEffective DateEnd DateJob Title
214520/02/201704/10/2020Job 1
214505/10/202018/04/2021Job 2
214519/04/202131/12/2222Job 1

 

But every time i group by i'm only getting 2 rows because the job titles for job 1 are the same.

Any ideas? can this even be done?

 

Thanks

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi  @emmabrice ,

Here are the steps you can follow:

1. Create calculated column.

Index = RANKX('Table',[Effective Date],,ASC,Dense)
Column =
var _lastrow=CALCULATE(MAX('Table'[Job Title]),FILTER(ALL('Table'),[Index]=EARLIER('Table'[Index])-1))
return
IF(_lastrow=[Job Title],0,1)
Group = SUMX(FILTER(ALL('Table'),[Index]<=EARLIER('Table'[Index])),[Column])

2. Create calculated table.

Table 2 =
var _summarize=
SUMMARIZE('Table',[PersonID],[Job Title],[Group],"1",MIN('Table'[Effective Date]),"2",MAX('Table'[End Date]))
return
SELECTCOLUMNS(_summarize,"PersonID",[PersonID],"Effective Date",[1],"End Date",[2],"Job Title",[Job Title])

3. Result:

vyangliumsft_0-1624267499568.png

 

 

Best Regards,

Liu Yang

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  @emmabrice ,

Here are the steps you can follow:

1. Create calculated column.

Index = RANKX('Table',[Effective Date],,ASC,Dense)
Column =
var _lastrow=CALCULATE(MAX('Table'[Job Title]),FILTER(ALL('Table'),[Index]=EARLIER('Table'[Index])-1))
return
IF(_lastrow=[Job Title],0,1)
Group = SUMX(FILTER(ALL('Table'),[Index]<=EARLIER('Table'[Index])),[Column])

2. Create calculated table.

Table 2 =
var _summarize=
SUMMARIZE('Table',[PersonID],[Job Title],[Group],"1",MIN('Table'[Effective Date]),"2",MAX('Table'[End Date]))
return
SELECTCOLUMNS(_summarize,"PersonID",[PersonID],"Effective Date",[1],"End Date",[2],"Job Title",[Job Title])

3. Result:

vyangliumsft_0-1624267499568.png

 

 

Best Regards,

Liu Yang

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

CNENFRNL
Community Champion
Community Champion

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("fZExCsMwDEWvUjwHpC9HxL5CrxCyFDIUCh3q+1O5rY0MST1ZvOcvIa9rEMwapiBMLCSMxYpoxdyK6/N2QdimrjKItVHMxPlUhTpq78DnqeIorAVqkQ5TxdFo6nKq1llTo33W41R1tKv5r1qpbeozuPDhAOoo0nevgp8qQ2p2tP6HenVIFThqG7CNiJ1BLfur1FRCa29Su5Z7eeyjGCm2RKUe3sXtDQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [PersonID = _t, #"Effective Date" = _t, #"End Date" = _t, #"Job Title" = _t]),
    #"Grouped Rows" = Table.Group(Source, {"PersonID", "Job Title"}, {{"ar", each _}}, 0, (x,y) => Number.From(x[PersonID]<>y[PersonID] or x[Job Title]<>y[Job Title])),
    Custom1 = Table.TransformColumns(#"Grouped Rows", {"ar", each let start=[Effective Date], end=[End Date] in [Start=start{0}, End=List.Last(end)]}),
    #"Expanded ar" = Table.ExpandRecordColumn(Custom1, "ar", {"Start", "End"}, {"Start", "End"})
in
    #"Expanded ar"

Screenshot 2021-06-18 123913.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 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.