Reply
Frequent Visitor
Posts: 6
Registered: ‎11-07-2018
Accepted Solution

Appending rows with adjacent time periodes.

[ Edited ]

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.


Accepted Solutions
Super User
Posts: 759
Registered: ‎09-16-2018

Re: Appending rows with adjacent time periodes.

 

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? Mark my post as a solution!


Proud to be a Datanaut!

View solution in original post


All Replies
Super User
Posts: 759
Registered: ‎09-16-2018

Re: Appending rows with adjacent time periodes.

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? Mark my post as a solution!


Proud to be a Datanaut!

Highlighted
Frequent Visitor
Posts: 6
Registered: ‎11-07-2018

Re: Appending rows with adjacent time periodes.

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

Super User
Posts: 759
Registered: ‎09-16-2018

Re: Appending rows with adjacent time periodes.

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? Mark my post as a solution!


Proud to be a Datanaut!

Frequent Visitor
Posts: 6
Registered: ‎11-07-2018

Re: Appending rows with adjacent time periodes.

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?

Super User
Posts: 759
Registered: ‎09-16-2018

Re: Appending rows with adjacent time periodes.

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? Mark my post as a solution!


Proud to be a Datanaut!

Frequent Visitor
Posts: 6
Registered: ‎11-07-2018

Re: Appending rows with adjacent time periodes.

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?

Super User
Posts: 759
Registered: ‎09-16-2018

Re: Appending rows with adjacent time periodes.

[ Edited ]

 

 

 



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


Proud to be a Datanaut!

Super User
Posts: 759
Registered: ‎09-16-2018

Re: Appending rows with adjacent time periodes.

 

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? Mark my post as a solution!


Proud to be a Datanaut!

Frequent Visitor
Posts: 6
Registered: ‎11-07-2018

Re: Appending rows with adjacent time periodes.

[ Edited ]

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.