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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Qlik333
Regular Visitor

Check if Date exists between 2 dates

I am using Power Query, and I have 2 tables that I am working with. I need to check if the route date (Table 1) exist in between 2 dates (from Table 2) and pull in the FY (Table 1).

 

Table 1

Route Date      FY

10/1/2019

6/17/2020

5/2/2021

 

Table 2

Start               End                   FY

10/1/2019      9/30/2020         FY20

10/1/2020      9/30/2021         FY21

10/1/2021      9/30/2022         FY22

1 ACCEPTED SOLUTION
CNENFRNL
Community Champion
Community Champion

Not necessary to quote any other calendar table since the FY end date ("9/30") is fixed all the time. One step is enough,

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjTQN9Q3MjC0VIrViVYy0zc0B/KMDMA8U30jEMdQKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Route Date" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Route Date", type date}}),

    FY = Table.AddColumn(#"Changed Type", "FY", each if Date.Month([Route Date]) > 9 then "FY" & Date.ToText(Date.EndOfYear([Route Date])+#duration(1,0,0,0), "yy") else "FY" & Date.ToText([Route Date], "yy"))
in
    FY

CNENFRNL_0-1647181076221.png

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

View solution in original post

4 REPLIES 4
CNENFRNL
Community Champion
Community Champion

Not necessary to quote any other calendar table since the FY end date ("9/30") is fixed all the time. One step is enough,

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjTQN9Q3MjC0VIrViVYy0zc0B/KMDMA8U30jEMdQKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Route Date" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Route Date", type date}}),

    FY = Table.AddColumn(#"Changed Type", "FY", each if Date.Month([Route Date]) > 9 then "FY" & Date.ToText(Date.EndOfYear([Route Date])+#duration(1,0,0,0), "yy") else "FY" & Date.ToText([Route Date], "yy"))
in
    FY

CNENFRNL_0-1647181076221.png

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Thank you!!

Vijay_A_Verma
Super User
Super User

Here is an alternative way by using Table.SelectRows - Solution file uploadd to -  

https://1drv.ms/x/s!Akd5y6ruJhvhuR_VfVLkonWse4WC?e=VrKpVz 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Route Date", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.SelectRows(Table2, (x)=> x[End]>=[Route Date] and x[Start]<=[Route Date]){0}[FY])
in
    #"Added Custom"

 

ronrsnfld
Super User
Super User

Here's one way:

 

let

//Read in the dates table
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    dateTable = Table.TransformColumnTypes(Source,{{"Route Date", type date}}),

//Read in the FY table
    Source2 = Excel.CurrentWorkbook(){[Name="Table2"]}[Content],
    fyTable=Table.TransformColumnTypes(Source2,{
        {"Start", type date},{"End", type date},{"FY", type text}
        }),

//Add a column to the FY table that includes all of the dates
    #"Added Custom" = Table.AddColumn(fyTable, "Custom", each List.Dates([Start], Duration.Days([End]-[Start])+1,#duration(1,0,0,0))),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),

//Join the two tables (JoinKind.LeftOuter) and return the FY
    joined = Table.Join(dateTable,"Route Date",#"Expanded Custom","Custom",JoinKind.LeftOuter),

//Remove unneeded columns
    #"Removed Columns" = Table.RemoveColumns(joined,{"Start", "End", "Custom"})
in
    #"Removed Columns"

 

 

ronrsnfld_0-1647137610869.png

 

 

 

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.