Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
Ran into an issue similar to This Question , I am doing something very similar but instead need much more resolution for the dates. What I have is the following starting table:
Ticket | Status | Date |
ABC123 | In Progress | 5/4/2023 |
ABC123 | Done | 5/7/2023 |
DEF456 | In Progress | 5/5/2023 |
LMN987 | In Progress | 5/7/2023 |
I am needing to fill in the dates up to the current date like:
Ticket | Status | Date |
ABC123 | In Progress | 5/4/2023 |
ABC123 | In Progress | 5/5/2023 |
DEF456 | In Progress | 5/5/2023 |
ABC123 | In Progress | 5/6/2023 |
DEF456 | In Progress | 5/6/2023 |
ABC123 | Done | 5/7/2023 |
LMN987 | In Progress | 5/7/2023 |
DEF456 | In Progress | 5/7/2023 |
ABC123 | Done | 5/8/2023 |
LMN987 | Done | 5/8/2023 |
DEF456 | Done | 5/8/2023 |
I am currently using the Power Query as well but pivoting then using the "fill in option" can't work since I do not know how many tickets I will have. Any help is grealy appreciated!
Solved! Go to Solution.
Hi @lgelfius ,
It seemst that what you want is to continue fill-in the date in between the status and still continue filling in the dates up to current even if the status is already one. If so, try this (filtered to ABC123 only).
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcnRyNjQyVtJR8sxTCCjKTy9KLS4G8gxM9Q1M9I0MgFKxOkiqXPLzUqHS5ghpF1c3E1MzrIaYIlT5+PpZWphjVQUzKxYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Ticket = _t, Status = _t, Date = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Ticket", type text}, {"Status", type text}}),
#"Changed Type with Locale" = Table.TransformColumnTypes(#"Changed Type", {{"Date", type date}}, "en-US"),
#"Grouped Rows" = Table.Group(#"Changed Type with Locale", {"Ticket"}, {{"Group", each _, type table [Ticket=nullable text, Status=nullable text, Date=nullable date]}}),
#"Added Custom" = Table.AddColumn(#"Grouped Rows", "DoneDate", each try Table.SelectRows([Group], each [Status] = "Done")[Date]{0} otherwise Date.From(DateTimeZone.LocalNow()), type date),
#"Expanded Group" = Table.ExpandTableColumn(#"Added Custom", "Group", {"Ticket", "Status", "Date"}, {"Ticket.1", "Status", "Date"}),
#"Filtered Rows" = Table.SelectRows(#"Expanded Group", each [Ticket] = "ABC123"),
#"Added Custom1" = Table.AddColumn(#"Filtered Rows", "Dates", each
let
donedate = [DoneDate],
maxdate = if [Status] = "Done" then Date.From(DateTime.LocalNow()) else Date.AddDays(donedate, -1),
count = Duration.Days(maxdate-[Date]) + 1
in List.Dates([Date], count, #duration(1,0,0,0))
, type list),
#"Expanded Dates" = Table.ExpandListColumn(#"Added Custom1", "Dates"),
#"Changed Type2" = Table.TransformColumnTypes(#"Expanded Dates",{{"Dates", type date}}),
#"Changed Type1" = Table.TransformColumnTypes(#"Changed Type2",{{"Dates", type date}})
in
#"Changed Type1"
Proud to be a Super User!
Hi @lgelfius ,
It seemst that what you want is to continue fill-in the date in between the status and still continue filling in the dates up to current even if the status is already one. If so, try this (filtered to ABC123 only).
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcnRyNjQyVtJR8sxTCCjKTy9KLS4G8gxM9Q1M9I0MgFKxOkiqXPLzUqHS5ghpF1c3E1MzrIaYIlT5+PpZWphjVQUzKxYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Ticket = _t, Status = _t, Date = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Ticket", type text}, {"Status", type text}}),
#"Changed Type with Locale" = Table.TransformColumnTypes(#"Changed Type", {{"Date", type date}}, "en-US"),
#"Grouped Rows" = Table.Group(#"Changed Type with Locale", {"Ticket"}, {{"Group", each _, type table [Ticket=nullable text, Status=nullable text, Date=nullable date]}}),
#"Added Custom" = Table.AddColumn(#"Grouped Rows", "DoneDate", each try Table.SelectRows([Group], each [Status] = "Done")[Date]{0} otherwise Date.From(DateTimeZone.LocalNow()), type date),
#"Expanded Group" = Table.ExpandTableColumn(#"Added Custom", "Group", {"Ticket", "Status", "Date"}, {"Ticket.1", "Status", "Date"}),
#"Filtered Rows" = Table.SelectRows(#"Expanded Group", each [Ticket] = "ABC123"),
#"Added Custom1" = Table.AddColumn(#"Filtered Rows", "Dates", each
let
donedate = [DoneDate],
maxdate = if [Status] = "Done" then Date.From(DateTime.LocalNow()) else Date.AddDays(donedate, -1),
count = Duration.Days(maxdate-[Date]) + 1
in List.Dates([Date], count, #duration(1,0,0,0))
, type list),
#"Expanded Dates" = Table.ExpandListColumn(#"Added Custom1", "Dates"),
#"Changed Type2" = Table.TransformColumnTypes(#"Expanded Dates",{{"Dates", type date}}),
#"Changed Type1" = Table.TransformColumnTypes(#"Changed Type2",{{"Dates", type date}})
in
#"Changed Type1"
Proud to be a Super User!
If you have only 1 or 2 rows per ticket, here's one way to do it in the query editor. To see how it works, just create a blank query, open the Advanced Editor and replace the text there with the M code below.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcnRyNjQyVtJR8sxTCCjKTy9KLS4G8kz1TfSNDIASsTpIalzy81LBkuYISRdXNxNTMywGmCLU+Pj6WVqYY1EDMycWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Ticket = _t, Status = _t, Date = _t]),
#"Pivoted Column" = Table.Pivot(Source, List.Distinct(Source[Status]), "Status", "Date"),
#"Replaced Value" = Table.ReplaceValue(#"Pivoted Column",null,Date.From(DateTime.LocalNow()),Replacer.ReplaceValue,{"Done"}),
#"Changed Type" = Table.TransformColumnTypes(#"Replaced Value",{{"Done", type date}, {"In Progress", type date}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Date", each List.Transform({Number.From([In Progress])..Number.From([Done])}, each Date.From(_) )),
#"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Ticket", "Date"}),
#"Expanded Date" = Table.ExpandListColumn(#"Removed Other Columns", "Date"),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded Date",{{"Date", type date}})
in
#"Changed Type1"
Pat
Hi @lgelfius
What is the end result you are trying to achieve? It looks like you're trying to track progress of tickets from create date to done date?
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
94 | |
92 | |
82 | |
71 | |
49 |
User | Count |
---|---|
143 | |
121 | |
111 | |
59 | |
57 |