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

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.

Reply
vojtechsima
Super User
Super User

Power Query LookUp (Time based)

Hello, guys

I am trying to retrieve a relevant "status" for Date/Time range for each row in Power Query. I have a History table with records, the History Value can be multiply values, I am looking to retrieve "Status" value.
I am using two identical tables, one to retrieve the information, one that I retriefe the information from:

 

LookupTable (Retrieve From):

 

vojtechsima_0-1635179976559.png

StatusTable (Retrieve To):

vojtechsima_1-1635180001771.png

However, I am getting error, that the "Key" matches to multiply values, however, it should be only one row due to the Formula.
The formula is here:

 

(let
Key = [Key], NewValueStart = [History New Value Start]
in
Table.SelectRows(LookupTable, each Key=[Key] and [History Field]="status" and NewValueStart >= [History New Value Start] and  NewValueStart <= [History New Value End Fixed]){0}[History Field Value])

 I am using a similar formula in other reports without issues. I am able to resolve this issue in DAX:

vojtechsima_2-1635180180116.png

with this formula: 

Status = 
var CurrentStatus = maxx(filter('LookupTable','LookupTable'[Key]=TimeInGroups[Key] && 'TimeInGroups'[History New Value Start] >= 'LookupTable'[History New Value Start] && TimeInGroups[History New Value Start] < 'LookupTable'[History New Value End Fixed] && 'LookupTable'[History Field]="status"),'LookupTable'[History New Value])
RETURN
IF(ISBLANK(CurrentStatus),"Not Assigned Yet",CurrentStatus)

However, I wanna do it in Power Query, could you please help me resolve this issue?

1 ACCEPTED SOLUTION

@vojtechsima  okay. The direct translation of  MAXX in PQ would be following. PBIX is attached

 

let
    a1 = Table.RenameColumns(let
        v1 = let
            v2 = Table.PrefixColumns(TimeInGroups, "a"),
            v3 = Table.PrefixColumns(LookupTable, "b"),
            v4 = Table.Join(v2, {"a.Key"}, v3, {"b.Key"}, JoinKind.LeftOuter, null)
        in
            v4,
        v6 = Table.SelectRows(v1, (v5) => Value.NullableEquals(v5[b.History_Field], "status")),
        v7 = Table.RenameColumns(v6, {{"b.History_New_Value_Start", "History_New_Value_StartB"}, {"b.History_New_Value", "History_New_ValueB"}}),
        v8 = Table.SelectColumns(v7, {"a.Index", "a.Key", "a.History_New_Value_End", "a.History_New_Value_Start", "a.History_Field", "a.History_New_Value", "a.Time_in_New_Value_businessHrs", "History_New_Value_StartB", "History_New_ValueB", "b.History_New_Value_End_Fixed"})
    in
        v8, {{"a.Index", "a1.Index"}, {"a.Key", "a1.Key"}, {"a.History_New_Value_End", "a1.History_New_Value_End"}, {"a.History_New_Value_Start", "a1.History_New_Value_Start"}, {"a.History_Field", "a1.History_Field"}, {"a.History_New_Value", "a1.History_New_Value"}, {"a.Time_in_New_Value_businessHrs", "a1.Time_in_New_Value_businessHrs"}, {"History_New_Value_StartB", "a1.History_New_Value_StartB"}, {"History_New_ValueB", "a1.History_New_ValueB"}, {"b.History_New_Value_End_Fixed", "a1.History_New_Value_End_Fixed"}})
in
    Table.RenameColumns(let
        v9 = a1,
        v11 = Table.SelectRows(v9, (v10) => v10[a1.History_New_Value_StartB] <= v10[a1.History_New_Value_Start] and v10[a1.History_New_Value_End_Fixed] > v10[a1.History_New_Value_Start]),
        v12 = Table.Group(v11, {"a1.Key", "a1.History_New_Value_End", "a1.History_New_Value_Start", "a1.History_Field", "a1.History_New_Value", "a1.Time_in_New_Value_businessHrs"}, {{"Status", (v13) => List.Max(v13[a1.History_New_ValueB])}}),
        v14 = Table.SelectColumns(v12, {"a1.Key", "a1.History_New_Value_End", "a1.History_New_Value_Start", "a1.History_Field", "a1.History_New_Value", "a1.Time_in_New_Value_businessHrs", "Status"})
    in
        v14, {{"a1.Key", "Key"}, {"a1.History_New_Value_End", "History_New_Value_End"}, {"a1.History_New_Value_Start", "History_New_Value_Start"}, {"a1.History_Field", "History_Field"}, {"a1.History_New_Value", "History_New_Value"}, {"a1.Time_in_New_Value_businessHrs", "Time_in_New_Value_businessHrs"}, {"Status", "Status"}})

 

 The above is written to mimic the following SQL

 

SELECT a.[key],
       a.history_new_value_end,
       a.history_new_value_start,
       a.history_field,
       a.history_new_value,
       a.time_in_new_value_business_hrs,
       Max(b.history_new_value) AS [Status]
FROM   [dbo].[timeingroups] a
       LEFT OUTER JOIN [dbo].[lookuptable] b
                    ON a.[key] = b.[key]
                       AND b.history_field = 'status'
                       AND b.history_new_value_start <= a.[history_new_value_start]
                       AND b.[history_new_value_end_fixed] > a.[history_new_value_start]
GROUP  BY a.[key],
          a.history_new_value_end,
          a.history_new_value_start,
          a.history_field,
          a.history_new_value,
          a.time_in_new_value_business_hrs 

 

 

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

View solution in original post

6 REPLIES 6
smpa01
Super User
Super User

@vojtechsima I can see that you have already written a PQWRY, I am not sure about the ask

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Hi, @smpa01 ,
I did not resolve it in Power Query, I am able to resolve it in DAX, but I can't figure it out in Power Query, I sent either a PBIX file or sample data, could you please give me a hint on how to write the code in Power Query, please?

@vojtechsima  okay. The direct translation of  MAXX in PQ would be following. PBIX is attached

 

let
    a1 = Table.RenameColumns(let
        v1 = let
            v2 = Table.PrefixColumns(TimeInGroups, "a"),
            v3 = Table.PrefixColumns(LookupTable, "b"),
            v4 = Table.Join(v2, {"a.Key"}, v3, {"b.Key"}, JoinKind.LeftOuter, null)
        in
            v4,
        v6 = Table.SelectRows(v1, (v5) => Value.NullableEquals(v5[b.History_Field], "status")),
        v7 = Table.RenameColumns(v6, {{"b.History_New_Value_Start", "History_New_Value_StartB"}, {"b.History_New_Value", "History_New_ValueB"}}),
        v8 = Table.SelectColumns(v7, {"a.Index", "a.Key", "a.History_New_Value_End", "a.History_New_Value_Start", "a.History_Field", "a.History_New_Value", "a.Time_in_New_Value_businessHrs", "History_New_Value_StartB", "History_New_ValueB", "b.History_New_Value_End_Fixed"})
    in
        v8, {{"a.Index", "a1.Index"}, {"a.Key", "a1.Key"}, {"a.History_New_Value_End", "a1.History_New_Value_End"}, {"a.History_New_Value_Start", "a1.History_New_Value_Start"}, {"a.History_Field", "a1.History_Field"}, {"a.History_New_Value", "a1.History_New_Value"}, {"a.Time_in_New_Value_businessHrs", "a1.Time_in_New_Value_businessHrs"}, {"History_New_Value_StartB", "a1.History_New_Value_StartB"}, {"History_New_ValueB", "a1.History_New_ValueB"}, {"b.History_New_Value_End_Fixed", "a1.History_New_Value_End_Fixed"}})
in
    Table.RenameColumns(let
        v9 = a1,
        v11 = Table.SelectRows(v9, (v10) => v10[a1.History_New_Value_StartB] <= v10[a1.History_New_Value_Start] and v10[a1.History_New_Value_End_Fixed] > v10[a1.History_New_Value_Start]),
        v12 = Table.Group(v11, {"a1.Key", "a1.History_New_Value_End", "a1.History_New_Value_Start", "a1.History_Field", "a1.History_New_Value", "a1.Time_in_New_Value_businessHrs"}, {{"Status", (v13) => List.Max(v13[a1.History_New_ValueB])}}),
        v14 = Table.SelectColumns(v12, {"a1.Key", "a1.History_New_Value_End", "a1.History_New_Value_Start", "a1.History_Field", "a1.History_New_Value", "a1.Time_in_New_Value_businessHrs", "Status"})
    in
        v14, {{"a1.Key", "Key"}, {"a1.History_New_Value_End", "History_New_Value_End"}, {"a1.History_New_Value_Start", "History_New_Value_Start"}, {"a1.History_Field", "History_Field"}, {"a1.History_New_Value", "History_New_Value"}, {"a1.Time_in_New_Value_businessHrs", "Time_in_New_Value_businessHrs"}, {"Status", "Status"}})

 

 The above is written to mimic the following SQL

 

SELECT a.[key],
       a.history_new_value_end,
       a.history_new_value_start,
       a.history_field,
       a.history_new_value,
       a.time_in_new_value_business_hrs,
       Max(b.history_new_value) AS [Status]
FROM   [dbo].[timeingroups] a
       LEFT OUTER JOIN [dbo].[lookuptable] b
                    ON a.[key] = b.[key]
                       AND b.history_field = 'status'
                       AND b.history_new_value_start <= a.[history_new_value_start]
                       AND b.[history_new_value_end_fixed] > a.[history_new_value_start]
GROUP  BY a.[key],
          a.history_new_value_end,
          a.history_new_value_start,
          a.history_field,
          a.history_new_value,
          a.time_in_new_value_business_hrs 

 

 

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
smpa01
Super User
Super User

@vojtechsima  any chance you can provide sample data and desired output?

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Hi, @smpa01 
Here is pasted text as Data source. 

 

KeyHistory New Value EndHistory New Value StartHistory FieldHistory New ValueTime in New Value (business hrs)Status_Result

SRVN-6236null25.10.2021 10:13:57statusResolved6,08Resolved
SRVN-623625.10.2021 10:13:5719.10.2021 8:06:48statusIn Progress33,2In Progress
SRVN-6236null19.10.2021 4:44:55Time To Resolution StatusBreached39,28Classification
SRVN-6236null13.10.2021 2:02:16Time To First Response StatusMet71,28Classification
SRVN-6236null12.10.2021 5:03:52Responsible TeamContact Center (VN)79,28Classification
SRVN-623619.10.2021 8:06:4812.10.2021 5:03:52statusClassification40Classification
SRVN-623612.10.2021 5:03:5212.10.2021 4:44:44statusNew0New
SRVN-623612.10.2021 5:03:5212.10.2021 4:44:43Responsible TeamService Desk (VN)0Waiting for approval
SRVN-623612.10.2021 4:44:4412.10.2021 4:44:42statusWaiting for approval0Waiting for approval


Thank you

Helpful resources

Announcements
October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

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.

Top Kudoed Authors