Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredJoin 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.
Hi! I'm new to power query and am stuck. I was able to manually create a table that works as needed in power bi but am having trouble automating its creation based on user inputs in an excel table. I got as far as unpivoting the table, but now I have a separate row for each milestone's start and end date. I would like each milestone to have its own row with a start and end date column.
Unpivoted table:
Here is a screenshot of the table that works in power bi as needed:
I want to move the end date value to a column next to the start date for each milestone, for each project. If I can provide better screenshots or sample data please let me know. Looking forward to your help!!
Solved! Go to Solution.
One approach would be as follows.
As an example, starting with...
and ending up with...
with the code...
let
Source =
Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("lZKxCoMwFEV/RTILaV6M2LFIC91ER3EIKjQgEUKkv19FWiE28blkeffm5YRT10SkQGKSl8V8cspSChcA0sTfSfkoonwyptc2qtpX301DH1VWGjsPGaOwFPhR4a47T7waB9UqK60adWARFeeK60KgiVu7vaXpdvl5ICjjSzhxWJ5aWSUHPPyugIT3LzqA9yz0wrv5HTzLxM+JjMJ1u2adnHAiUPj3LWsc6wS4T8Y5wdwa0omNBelEoICEDzgRhvc64YEPO9F8AA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ProjectID = _t, Milestone = _t, #"Start Date" = _t]),
changeDataTypes =
Table.TransformColumnTypes(Source,{{"ProjectID", Int64.Type}, {"Milestone", type text}, {"Start Date", type date}}),
addStartDate =
Table.AddColumn(changeDataTypes, "sDate", each if not Text.EndsWith([Milestone], "End") then [Start Date] else null, type date),
addEndDate =
Table.AddColumn(addStartDate, "eDate", each if Text.EndsWith([Milestone], "Start") then null else [Start Date], type date),
fillUpEndDate =
Table.FillUp(addEndDate,{"eDate"}),
cleanMilestones =
Table.TransformColumns(fillUpEndDate, {{"Milestone", each if Text.EndsWith(_, "Start") or Text.EndsWith(_, "End") then Text.BeforeDelimiter(_, " ", RelativePosition.FromEnd) else _, type text}}),
filterRows =
Table.SelectRows(cleanMilestones, each ([sDate] <> null)),
removeOriginalDate =
Table.RemoveColumns(filterRows,{"Start Date"}),
renameColumns =
Table.RenameColumns(removeOriginalDate,{{"sDate", "Start Date"}, {"eDate", "End Date"}})
in
renameColumns
Proud to be a Super User! | |
Sure thing.
In the code I posted, everything from "addStartDate = ..." and down is what you would add to your existing code. You would also have to change the 'changeDataTypes' to the name of the previous step in your code.
addStartDate =
Table.AddColumn(changeDataTypes, "sDate", each if not Text.EndsWith([Milestone], "End") then [Start Date] else null, type date)
Assuming your column names are the same as what you posted, there should not be anything else to change.
Feel free to send me a private message if you need anything further.
Proud to be a Super User! | |
One approach would be as follows.
As an example, starting with...
and ending up with...
with the code...
let
Source =
Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("lZKxCoMwFEV/RTILaV6M2LFIC91ER3EIKjQgEUKkv19FWiE28blkeffm5YRT10SkQGKSl8V8cspSChcA0sTfSfkoonwyptc2qtpX301DH1VWGjsPGaOwFPhR4a47T7waB9UqK60adWARFeeK60KgiVu7vaXpdvl5ICjjSzhxWJ5aWSUHPPyugIT3LzqA9yz0wrv5HTzLxM+JjMJ1u2adnHAiUPj3LWsc6wS4T8Y5wdwa0omNBelEoICEDzgRhvc64YEPO9F8AA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ProjectID = _t, Milestone = _t, #"Start Date" = _t]),
changeDataTypes =
Table.TransformColumnTypes(Source,{{"ProjectID", Int64.Type}, {"Milestone", type text}, {"Start Date", type date}}),
addStartDate =
Table.AddColumn(changeDataTypes, "sDate", each if not Text.EndsWith([Milestone], "End") then [Start Date] else null, type date),
addEndDate =
Table.AddColumn(addStartDate, "eDate", each if Text.EndsWith([Milestone], "Start") then null else [Start Date], type date),
fillUpEndDate =
Table.FillUp(addEndDate,{"eDate"}),
cleanMilestones =
Table.TransformColumns(fillUpEndDate, {{"Milestone", each if Text.EndsWith(_, "Start") or Text.EndsWith(_, "End") then Text.BeforeDelimiter(_, " ", RelativePosition.FromEnd) else _, type text}}),
filterRows =
Table.SelectRows(cleanMilestones, each ([sDate] <> null)),
removeOriginalDate =
Table.RemoveColumns(filterRows,{"Start Date"}),
renameColumns =
Table.RenameColumns(removeOriginalDate,{{"sDate", "Start Date"}, {"eDate", "End Date"}})
in
renameColumns
Proud to be a Super User! | |
I've been stuck for days and this such a simple solution
thank you
Thank you! This is exactly what I need! Can you help me with which parts I need to update to apply this to my whole data set? I'm able to recreate just your example here.
Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!
Check out the October 2025 Power BI update to learn about new features.