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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
PBIX123
Frequent Visitor

Power Query - Fill Down per ID (- with conditions)

Hi, I have a data similar as shown below, with ID, DATE_TIME and unpivoted timestamp columns (e.g. TIME1, TIME2, TIME3). I want to flatten all timestamps per ID into 1 row and take the Max DATE_TIME. Managed to do Group By and take Max DATE_TIME as suggested by @MarcelBeug from https://community.powerbi.com/t5/Desktop/Latest-Record-in-Group-via-Query-Editor/td-p/225190. However, I have difficulties with fill down only per ID. 

 

Sample of the raw data I have and the desired output. Thank you in advance! Smiley Happy

 

Capture.PNG

1 ACCEPTED SOLUTION
Zubair_Muhammad
Community Champion
Community Champion

@PBIX123

 

Try this

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTIw1PVKzNM1tACyDYEYhGJ1oHKmCDkgMkGRM0ORAyJzsJwTSM4cRc4Ups8ZJGeMImeGIofkFmMkt4DNNELIGSHJOWN1i4VSbCwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, DATE_TIME = _t, TIME1 = _t, TIME2 = _t, TIME3 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"DATE_TIME", type date}, {"TIME1", Int64.Type}, {"TIME2", Int64.Type}, {"TIME3", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"1", each _, type table}, {"2", each _, type table}, {"3", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "TIME1", each Table.SelectRows([1],each [TIME1]>0)),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "TIME2", each Table.SelectRows([2],each [TIME2]>0)),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "TIME3", each Table.SelectRows([3],each [TIME3]>0)),
    #"Expanded TIME1" = Table.ExpandTableColumn(#"Added Custom2", "TIME1", {"TIME1"}, {"TIME1"}),
    #"Expanded TIME2" = Table.ExpandTableColumn(#"Expanded TIME1", "TIME2", {"TIME2"}, {"TIME2"}),
    #"Expanded TIME3" = Table.ExpandTableColumn(#"Expanded TIME2", "TIME3", {"TIME3"}, {"TIME3"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded TIME3",{"1", "2", "3"})
in
    #"Removed Columns"

Regards
Zubair

Please try my custom visuals

View solution in original post

3 REPLIES 3
Zubair_Muhammad
Community Champion
Community Champion

@PBIX123

 

Try this

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTIw1PVKzNM1tACyDYEYhGJ1oHKmCDkgMkGRM0ORAyJzsJwTSM4cRc4Ups8ZJGeMImeGIofkFmMkt4DNNELIGSHJOWN1i4VSbCwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, DATE_TIME = _t, TIME1 = _t, TIME2 = _t, TIME3 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"DATE_TIME", type date}, {"TIME1", Int64.Type}, {"TIME2", Int64.Type}, {"TIME3", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"1", each _, type table}, {"2", each _, type table}, {"3", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "TIME1", each Table.SelectRows([1],each [TIME1]>0)),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "TIME2", each Table.SelectRows([2],each [TIME2]>0)),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "TIME3", each Table.SelectRows([3],each [TIME3]>0)),
    #"Expanded TIME1" = Table.ExpandTableColumn(#"Added Custom2", "TIME1", {"TIME1"}, {"TIME1"}),
    #"Expanded TIME2" = Table.ExpandTableColumn(#"Expanded TIME1", "TIME2", {"TIME2"}, {"TIME2"}),
    #"Expanded TIME3" = Table.ExpandTableColumn(#"Expanded TIME2", "TIME3", {"TIME3"}, {"TIME3"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded TIME3",{"1", "2", "3"})
in
    #"Removed Columns"

Regards
Zubair

Please try my custom visuals

@PBIX123

 

Please see the attached File's Query Editor to see the steps

 

PQ_.png


Regards
Zubair

Please try my custom visuals

It works! Thanks a bunch! 🙂

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.