cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
sosje
Helper I
Helper I

Appending rows with adjacent time periodes.

Hello, I need som help.

 

I have data with a start and end date. I need to merge rows where a period begins immediately after another period has ended eg 31-12-2017 and starts 1-1-2018 so they become one row. Only rows for the same ID, name and item is to be joined.

 

So how to get from "Data as is" to "Data wanted"?

 

Example:

 Appending rows data excample.JPG

 


I think the right place for the transformation is in the query (M language) but a solution in DAX is also welcome.

1 ACCEPTED SOLUTION

 

Hi @sosje

 

you need to add the below small modifications to my previous code:

 

GroupKind.Local at the end of the 3rd step:

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQ0VNJR8krMSwVSzolFQNLQSN8IiAwMzSEcY0MIJ1YHu3J9sLwFhGkAYWOodSxILCrJTc0rAbJN9Q3hxqPoMDIyAinNSU0GUu75OWkKQCtAOswQOsz0jRHOwdQQnIqhHmIDLg1wG8yw6zA2NgaK+eUX5WK6CdkSU3xa4K5CssQIZkksAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t, Item = _t, DateStart = _t, DateEnd = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Name", type text}, {"Item", type text}, {"DateStart", type date}, {"DateEnd", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID", "Name", "Item"}, {{"DateStart", each List.Min([DateStart]), type date}, {"DateEnd", each List.Max([DateEnd]), type date}}, GroupKind.Local)
in
    #"Grouped Rows"

 

Capture.PNG

 

 


 


Did I answer your question correctly? Mark my answer as a solution!


Proud to be a Datanaut!  

View solution in original post

10 REPLIES 10
LivioLanzo
Solution Sage
Solution Sage

Hello @sosje

 

I believe in this particular case you just need to group by ID, Name, Item and then take the MIN of DateStart and the MAX of DateEnd

 

 

 


 


Did I answer your question correctly? Mark my answer as a solution!


Proud to be a Datanaut!  

Hi Livio thanks for the answer. Can you elaborate on that? I do not understand how to reach the table shown as "Data wanted"

Hi @sosje

 

Power Query has a GROUP BY function which can do this for you, here is how to use it:

 

https://support.office.com/en-us/article/group-rows-in-a-table-power-query-e1b9e916-6fcc-40bf-a6e8-e...

 


 


Did I answer your question correctly? Mark my answer as a solution!


Proud to be a Datanaut!  

Hi again Livio

 

I know about the GROUP BY function, but I still dont see how to get the transformation done. In my example it is only the red rows that should change.

Rows with same ID, name and item and an end date that is the day before the start date of an other row with same ID, name and item should become one row with the full periode.

 

Could you show how to do by excample?

Hi @sosje

 

paste this code in the power query advanced editor:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQ0VNJR8krMSwVSzolFQNLQSN8IiAwMzSEcY0MIJ1YHu3J9sLwFhGkAYWOodSxILCrJTc0rAbJN9Q3hxqPoMDIyAinNSU0GUu75OWkKQCtAOswQOsz0jRHOwdQQnIqhHmIDLg1wG8yw6zA2NgaK+eUX5WK6CdkSU3xa4K5CssQIZkksAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t, Item = _t, DateStart = _t, DateEnd = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Name", type text}, {"Item", type text}, {"DateStart", type date}, {"DateEnd", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID", "Name", "Item"}, {{"DateStart", each List.Min([DateStart]), type date}, {"DateEnd", each List.Max([DateEnd]), type date}})
in
    #"Grouped Rows"

 


 


Did I answer your question correctly? Mark my answer as a solution!


Proud to be a Datanaut!  

Hi Livio

 

Thanks for the code and your effort.

 

When I run the code I get:

 

Appending rows data query.JPG

 

which is not what I want. I want the result shown above under "Wanted data". Am I missing some thing?

 

 

 

 


 


Did I answer your question correctly? Mark my answer as a solution!


Proud to be a Datanaut!  

 

Hi @sosje

 

you need to add the below small modifications to my previous code:

 

GroupKind.Local at the end of the 3rd step:

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQ0VNJR8krMSwVSzolFQNLQSN8IiAwMzSEcY0MIJ1YHu3J9sLwFhGkAYWOodSxILCrJTc0rAbJN9Q3hxqPoMDIyAinNSU0GUu75OWkKQCtAOswQOsz0jRHOwdQQnIqhHmIDLg1wG8yw6zA2NgaK+eUX5WK6CdkSU3xa4K5CssQIZkksAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t, Item = _t, DateStart = _t, DateEnd = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Name", type text}, {"Item", type text}, {"DateStart", type date}, {"DateEnd", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID", "Name", "Item"}, {{"DateStart", each List.Min([DateStart]), type date}, {"DateEnd", each List.Max([DateEnd]), type date}}, GroupKind.Local)
in
    #"Grouped Rows"

 

Capture.PNG

 

 


 


Did I answer your question correctly? Mark my answer as a solution!


Proud to be a Datanaut!  

Hi Livio

 

It is working perfectly now. I had some problems due to the date format in the source, as I use the date format 31-12-2017 and not 12/31/2017.

 

Thank you very much.

After I have worked with the solution I find that the grouping is dependent on the sorting of the table when using "GroupKind.Local".

If I sort the table by ID and item, which seems logical, I do not get the desired result where only continuous periods eg end 31-12-2017 and start 01-01-2018 appear as one period. Eg. the periods for Alec, Golf cart (dd-mm-yyyy) 01-06-2017 to 03-06-2017 and 06-06-2017 to 10-06-2017 becoms the period 01-06-2017 to 10-06-2017, where they should continue to be two periods.

 

Someone who can help?

 

Appending rows data query sorting.JPG

Helpful resources

Announcements
August 1 episode 9_no_dates 768x460.jpg

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power BI Dev Camp Session 24 without aka link and time 768x460.jpg

Ted's Dev Camp - July 28, 2022

Watch Session 24 of Ted's Dev Camp along with past sessions!

Power Platform Conf 2022 768x460.jpg

Join us for Microsoft Power Platform Conference

The first Microsoft-sponsored Power Platform Conference is coming in September. 100+ speakers, 150+ sessions, and what's new and next for Power Platform.

Top Solution Authors
Top Kudoed Authors