Join 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!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hello,
I need to filter my data in Power Query where TODAY is between FROM_DATE & TO_DATE and return the MAIN_PRICE. If TODAY is not falling between those two dates, return the MAIN_PRICE of the LATEST KNOWN DATE (max date available).
Data Source:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hdFRDsMgCAbgqzRmj00EVISzNL3/NSYqi1nX1Zdq8n9Q8TgCZtEc9kAkUu0bIUUCgrZPGBH8sL0QYAvnfjUthh6jEoHsgMMUNwWTGaQkPGtbDrkXALV97SbDjaEl5kQ7KU9EPy21rW74YhT7X7c7Q/Y+8zoo/w0vMe85SL0jaYlNPgctThIQkxGuWqxyjSBusCFeR/DbYF1iXyMYL3q+AQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ITEM_NO = _t, SUP_NO = _t, FROM_DATE = _t, TO_DATE = _t, PUA_MAIN_PRICE = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ITEM_NO", type text}, {"SUP_NO", type text}, {"FROM_DATE", type date}, {"TO_DATE", type date}, {"PUA_MAIN_PRICE", Currency.Type}})
in
#"Changed Type"
Thanks a lot in advance,
Cheers.
Solved! Go to Solution.
Hi @Anonymous
Here is one way, change the currency to number
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hZFBEsMgCEXv4joz8lERzpLJ/a9RSLW1bdq6Ecb3QHTfE6paTVtiVu2xZyqZicnjggyaCYjSsX0KzmAy3DJxJIiDNoSGEgK4qIyqAUFOmyziqFTpWuCFmbx53P7w9mhmvjyRd8FwvyllqrPDGAH6Q5CFmd0i7l/4sjDDPd9LB1+IhYOXbi1q9kw6Bbghz5kvBfSFeZn5/LbjBg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ITEM_NO = _t, SUP_NO = _t, FROM_DATE = _t, TO_DATE = _t, PUA_MAIN_PRICE = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ITEM_NO", type text}, {"SUP_NO", type text}, {"FROM_DATE", type date}, {"TO_DATE", type date}, {"PUA_MAIN_PRICE", Int64.Type}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"ITEM_NO", "SUP_NO"}, {{"max", each List.Max([TO_DATE]), type nullable date}}),
#"Merged Queries" = Table.NestedJoin(#"Grouped Rows", {"ITEM_NO", "SUP_NO", "max"}, #"Changed Type", {"ITEM_NO", "SUP_NO", "TO_DATE"}, "Grouped Rows", JoinKind.LeftOuter),
maxTable = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"PUA_MAIN_PRICE"}, {"PUA_MAIN_PRICE"}),
Custom2 = Table.NestedJoin(#"Changed Type", {"ITEM_NO", "SUP_NO"}, maxTable, {"ITEM_NO", "SUP_NO"}, "Grouped Rows", JoinKind.LeftOuter),
#"Expanded Grouped Rows" = Table.ExpandTableColumn(Custom2, "Grouped Rows", {"PUA_MAIN_PRICE"}, {"max.PUA_MAIN_PRICE"}),
Custom1 = Table.AddColumn(#"Expanded Grouped Rows", "RESULT", each if Date.From( DateTime.LocalNow())>=[FROM_DATE] and Date.From( DateTime.LocalNow())<=[TO_DATE] then [PUA_MAIN_PRICE] else [max.PUA_MAIN_PRICE]),
#"Removed Columns" = Table.RemoveColumns(Custom1,{"max.PUA_MAIN_PRICE"})
in
#"Removed Columns"
Thanks @Vera_33, works wonders.
One additional question, how would you now filter the data to keep only those rows where today is between both dates and also keeping the row for those with the last known date leaving out all the other rows which are not necessary (older dates).
Keep highligted rows:
I have managed a solution but maybe you have a less complicated one or better performance wise. Curious to learn more alternatives.
Thank you!
Hi @Anonymous
If you only need to keep the rows, then no need to find the Price then compare, so here is one way
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hZFBEsMgCEXv4joz8lERzpLJ/a9RSLW1bdq6Ecb3QHTfE6paTVtiVu2xZyqZicnjggyaCYjSsX0KzmAy3DJxJIiDNoSGEgK4qIyqAUFOmyziqFTpWuCFmbx53P7w9mhmvjyRd8FwvyllqrPDGAH6Q5CFmd0i7l/4sjDDPd9LB1+IhYOXbi1q9kw6Bbghz5kvBfSFeZn5/LbjBg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ITEM_NO = _t, SUP_NO = _t, FROM_DATE = _t, TO_DATE = _t, PUA_MAIN_PRICE = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ITEM_NO", type text}, {"SUP_NO", type text}, {"FROM_DATE", type date}, {"TO_DATE", type date}, {"PUA_MAIN_PRICE", Int64.Type}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"ITEM_NO", "SUP_NO"}, {{"maxDate", each List.Max([TO_DATE]), type nullable date}}),
#"Merged Queries" = Table.NestedJoin( #"Changed Type", {"ITEM_NO", "SUP_NO", "TO_DATE"},#"Grouped Rows", {"ITEM_NO", "SUP_NO", "maxDate"}, "Grouped Rows", JoinKind.LeftOuter),
#"Expanded Grouped Rows" = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"maxDate"}),
#"Added Custom" = Table.AddColumn(#"Expanded Grouped Rows", "check", each if Date.From( DateTime.LocalNow())>=[FROM_DATE] and Date.From( DateTime.LocalNow())<=[TO_DATE] then 1
else if [maxDate] <> null then 1 else 0),
#"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([check] = 1)),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"maxDate", "check"})
in
#"Removed Columns"
Hi @Anonymous
Here is one way, change the currency to number
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hZFBEsMgCEXv4joz8lERzpLJ/a9RSLW1bdq6Ecb3QHTfE6paTVtiVu2xZyqZicnjggyaCYjSsX0KzmAy3DJxJIiDNoSGEgK4qIyqAUFOmyziqFTpWuCFmbx53P7w9mhmvjyRd8FwvyllqrPDGAH6Q5CFmd0i7l/4sjDDPd9LB1+IhYOXbi1q9kw6Bbghz5kvBfSFeZn5/LbjBg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ITEM_NO = _t, SUP_NO = _t, FROM_DATE = _t, TO_DATE = _t, PUA_MAIN_PRICE = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ITEM_NO", type text}, {"SUP_NO", type text}, {"FROM_DATE", type date}, {"TO_DATE", type date}, {"PUA_MAIN_PRICE", Int64.Type}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"ITEM_NO", "SUP_NO"}, {{"max", each List.Max([TO_DATE]), type nullable date}}),
#"Merged Queries" = Table.NestedJoin(#"Grouped Rows", {"ITEM_NO", "SUP_NO", "max"}, #"Changed Type", {"ITEM_NO", "SUP_NO", "TO_DATE"}, "Grouped Rows", JoinKind.LeftOuter),
maxTable = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"PUA_MAIN_PRICE"}, {"PUA_MAIN_PRICE"}),
Custom2 = Table.NestedJoin(#"Changed Type", {"ITEM_NO", "SUP_NO"}, maxTable, {"ITEM_NO", "SUP_NO"}, "Grouped Rows", JoinKind.LeftOuter),
#"Expanded Grouped Rows" = Table.ExpandTableColumn(Custom2, "Grouped Rows", {"PUA_MAIN_PRICE"}, {"max.PUA_MAIN_PRICE"}),
Custom1 = Table.AddColumn(#"Expanded Grouped Rows", "RESULT", each if Date.From( DateTime.LocalNow())>=[FROM_DATE] and Date.From( DateTime.LocalNow())<=[TO_DATE] then [PUA_MAIN_PRICE] else [max.PUA_MAIN_PRICE]),
#"Removed Columns" = Table.RemoveColumns(Custom1,{"max.PUA_MAIN_PRICE"})
in
#"Removed Columns"
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
Check out the November 2025 Power BI update to learn about new features.