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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Coltella8013
Frequent Visitor

Help converting list of items with date range into (with gaps in date range)

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:

ItemTypeStart DateEnd DateGap 1 StartGap 1 EndGap 2 StartGap 2 End
Item 1Type 101/01/202110/01/202103/01/202104/01/2021  
Item 2Type 203/01/202110/01/202104/01/202105/01/202108/01/202109/01/2021
Item 3Type 105/01/202110/01/2021    
Item 4Type 107/01/202108/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

3 REPLIES 3
AlB
Super User
Super User

@Coltella8013 

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"

 

 

SU18_powerbi_badge

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.

 

AlB
Super User
Super User

Hi @Coltella8013 

What is the expected output for the sample data you are showing?

 

SU18_powerbi_badge

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.

 

Coltella8013_0-1621847286798.png

Many thanks.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

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.

Top Solution Authors