Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Hey.
I am currently using the suggested conversion column conversion as suggested here: Solved: Help converting list of items with date range into... - Microsoft Power BI Community
I now need to exclude some gaps within the date range but am unsure how to achieve this using the custom field formula.
Table Source Data Example:
Item | Type | Start Date | End Date | Gap 1 Start | Gap 1 End | Gap 2 Start | Gap 2 End |
Item 1 | Type 1 | 01/01/2021 | 10/01/2021 | 03/01/2021 | 04/01/2021 | ||
Item 2 | Type 2 | 03/01/2021 | 10/01/2021 | 04/01/2021 | 05/01/2021 | 08/01/2021 | 09/01/2021 |
Item 3 | Type 1 | 05/01/2021 | 10/01/2021 | ||||
Item 4 | Type 1 | 07/01/2021 | 08/01/2021 |
Using:
{Number.From([Start Date])..Number.From([End Date])}
I am looking to achieve the same but with the dates that fall between Gap 1 Start and Gap 1 End, and also Gap 2 Start and Gap 2 End Where they exist. Where they don't exist then the original formula is used.
Any help kindly appreciated.
Nigel
Place the following M code in a blank query to see the steps.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8ixJzVUwVNJRCqksSAUzDAz1gcjIwAjEMTRA4hgYI3NMkDgKYByrAzXPCGaeEbouVPOQjTAwReZYIHMs4Ry4DcYoLjbFZYMCCobrNkHRbY7LYpAuKIqNBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Item = _t, Type = _t, #"Start Date" = _t, #"End Date" = _t, #"Gap 1 Start" = _t, #"Gap 1 End" = _t, #"Gap 2 Start" = _t, #"Gap 2 End" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Item", type text}, {"Type", type text}, {"Start Date", type date}, {"End Date", type date}, {"Gap 1 Start", type date}, {"Gap 1 End", type date}, {"Gap 2 Start", type date}, {"Gap 2 End", type date}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Total", each let total_ = {Number.From([Start Date])..Number.From([End Date])},
gap1_ = try {Number.From([Gap 1 Start])..Number.From([Gap 1 End])} otherwise {},
gap2_ = try {Number.From([Gap 2 Start])..Number.From([Gap 2 End])} otherwise {},
gaps_ = gap1_ & gap2_,
res_ = List.Select(total_,each not List.Contains(gaps_, _))
in res_),
#"Expanded Total" = Table.ExpandListColumn(#"Added Custom", "Total"),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded Total",{{"Total", type date}}),
#"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"Start Date", "End Date", "Gap 1 Start", "Gap 1 End", "Gap 2 Start", "Gap 2 End"}),
#"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"Total", "Item", "Type"})
in
#"Reordered Columns"
|
Please accept the solution when done and consider giving a thumbs up if posts are helpful. Contact me privately for support with any larger-scale BI needs, tutoring, etc. |
What is the expected output for the sample data you are showing?
|
Please accept the solution when done and consider giving a thumbs up if posts are helpful. Contact me privately for support with any larger-scale BI needs, tutoring, etc. |
Hi
It would be similar to this but without the dates that fall between the GAP fields (excluding the last date in the range). Notice the strike through's below that were the dates from the Gap date ranges.
Many thanks.