Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
I need to combine these rows into one row.
What I would like to end up with is this
It should be based on Date Time and DocNo
There are cases of duplicates.
In these cases I would like to keep the min
Solved! Go to Solution.
try this code to see how using Text.Combine and Split to achieve your objective.
This works on the assumption that you have two lines of entry for each assignment.
You referred to using min. You can consider ranking and retaining top two records for each group as your change record.
Please mark resolved if it works for you.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjTXNbDUNTIwMlGwsDI1sDIxUXD0VdJRCvB09jY0NDA0NgZyHIuLM9PzclPzShRCMnNTgSKGJlZGBlYGhnqmhiAFBhC9RnoGFsZQzUqxOmSbDtIA0mhohswxh5scCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Date Time" = _t, docNo = _t, fieldCaption = _t, oldValue = _t, newValue = _t, userID = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Date Time", type datetime}, {"docNo", type text}, {"fieldCaption", type text}, {"oldValue", type text}, {"newValue", type text}, {"userID", type text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Date Time", "docNo", "fieldCaption", "userID"}, {{"DATA", each _, type table [Date Time=nullable datetime, docNo=nullable text, fieldCaption=nullable text, oldValue=nullable text, newValue=nullable text, userID=nullable text]}}),
#"Added Custom List oldValue" = Table.AddColumn(#"Grouped Rows", "oldValue", each Text.Combine([DATA][oldValue], "|")),
#"Added Custom List newValue" = Table.AddColumn(#"Added Custom List oldValue", "newValue", each Text.Combine([DATA][newValue], "|")),
#"Split Column by Delimiter" = Table.SplitColumn(#"Added Custom List newValue", "oldValue", Splitter.SplitTextByDelimiter("|", QuoteStyle.Csv), {"oldValue.1", "oldValue.2"}),
#"Changed Type1 delimiter oldValue" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"oldValue.1", type time}, {"oldValue.2", type date}}),
#"Split Column by Delimiter1" = Table.SplitColumn(#"Changed Type1 delimiter oldValue", "newValue", Splitter.SplitTextByDelimiter("|", QuoteStyle.Csv), {"newValue.1", "newValue.2"}),
#"Changed Type2" = Table.TransformColumnTypes(#"Split Column by Delimiter1",{{"newValue.1", type time}, {"newValue.2", type date}}),
#"Renamed Columns" = Table.RenameColumns(#"Changed Type2",{{"oldValue.1", "Assignment Time oldValue"}, {"oldValue.2", "Assignment Date oldValue"}, {"newValue.1", "Assignment Time newValue"}, {"newValue.2", "Assignment Date newValue"}})
in
#"Renamed Columns"
You can use Group By, but for accurate solution please share your data as table here
try this code to see how using Text.Combine and Split to achieve your objective.
This works on the assumption that you have two lines of entry for each assignment.
You referred to using min. You can consider ranking and retaining top two records for each group as your change record.
Please mark resolved if it works for you.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjTXNbDUNTIwMlGwsDI1sDIxUXD0VdJRCvB09jY0NDA0NgZyHIuLM9PzclPzShRCMnNTgSKGJlZGBlYGhnqmhiAFBhC9RnoGFsZQzUqxOmSbDtIA0mhohswxh5scCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Date Time" = _t, docNo = _t, fieldCaption = _t, oldValue = _t, newValue = _t, userID = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Date Time", type datetime}, {"docNo", type text}, {"fieldCaption", type text}, {"oldValue", type text}, {"newValue", type text}, {"userID", type text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Date Time", "docNo", "fieldCaption", "userID"}, {{"DATA", each _, type table [Date Time=nullable datetime, docNo=nullable text, fieldCaption=nullable text, oldValue=nullable text, newValue=nullable text, userID=nullable text]}}),
#"Added Custom List oldValue" = Table.AddColumn(#"Grouped Rows", "oldValue", each Text.Combine([DATA][oldValue], "|")),
#"Added Custom List newValue" = Table.AddColumn(#"Added Custom List oldValue", "newValue", each Text.Combine([DATA][newValue], "|")),
#"Split Column by Delimiter" = Table.SplitColumn(#"Added Custom List newValue", "oldValue", Splitter.SplitTextByDelimiter("|", QuoteStyle.Csv), {"oldValue.1", "oldValue.2"}),
#"Changed Type1 delimiter oldValue" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"oldValue.1", type time}, {"oldValue.2", type date}}),
#"Split Column by Delimiter1" = Table.SplitColumn(#"Changed Type1 delimiter oldValue", "newValue", Splitter.SplitTextByDelimiter("|", QuoteStyle.Csv), {"newValue.1", "newValue.2"}),
#"Changed Type2" = Table.TransformColumnTypes(#"Split Column by Delimiter1",{{"newValue.1", type time}, {"newValue.2", type date}}),
#"Renamed Columns" = Table.RenameColumns(#"Changed Type2",{{"oldValue.1", "Assignment Time oldValue"}, {"oldValue.2", "Assignment Date oldValue"}, {"newValue.1", "Assignment Time newValue"}, {"newValue.2", "Assignment Date newValue"}})
in
#"Renamed Columns"
Please provide sample data that covers your issue or question completely, in a usable format (not as a screenshot).
Do not include sensitive information or anything not related to the issue or question.
If you are unsure how to upload data please refer to https://community.fabric.microsoft.com/t5/Community-Blog/How-to-provide-sample-data-in-the-Power-BI-...
Please show the expected outcome based on the sample data you provided.
Want faster answers? https://community.fabric.microsoft.com/t5/Desktop/How-to-Get-Your-Question-Answered-Quickly/m-p/1447...
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
Check out the November 2025 Power BI update to learn about new features.