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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
Anonymous
Not applicable

Search Results within the same query

Hi, I have a very basic question.

I want to create a conditional column that does a "sort" of VLOOKUP witihin the query itself ...!

 

I need to see if an employee's manager is INACTIVE and, if yes, give me as result the manager's manager.

 

Here the data sample and the expected results.

 

SEARCH MANAGER ID IN THE EMPLOYEE ID COLUMN, IF EMPLOYEE ID IS INACTIVE, RESULT IS MANAGER'S ID , ELSE, DO NOTHING.

 

EMPOLYEE IDSTATUSMANAGER
1active2
2active1
3active6
4active6
5active7
6INACTIVE8
7INACTIVE9
8active10
9active10
10active10

 

1 ACCEPTED SOLUTION
Mariusz
Community Champion
Community Champion

Hi @Anonymous 

 

Try the below if it works for you 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUUpMLsksSwUyjJRidaKBJJKQIVjIGFnIDCxkgilkiixkDhYyA7I8/RydQzzDXIFMC7CgOaqgJVjQAsVWA7CYJRYxIIUmGAsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"EMPOLYEE ID" = _t, STATUS = _t, MANAGER = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"EMPOLYEE ID", Int64.Type}, {"STATUS", type text}, {"MANAGER", Int64.Type}}),
    #"Next Line Up Menager" = 
        let 
            #"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([STATUS] = "INACTIVE")),
            #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"MANAGER"}, #"Filtered Rows", {"EMPOLYEE ID"}, "Changed Type", JoinKind.LeftOuter)
        in
            #"Merged Queries",
    #"Expanded Changed Type" = Table.ExpandTableColumn(#"Next Line Up Menager", "Changed Type", {"MANAGER"}, {"Next Line Up Menager"})
in
    #"Expanded Changed Type"
Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
Mariusz Repczynski

 

View solution in original post

12 REPLIES 12
Anonymous
Not applicable

Hi @Anonymous ,

 

Is this guaranteed that the manager of an inactive manager will be active (simple)?

Or it is possible that two levels in sequence can be "inactive" (more complicated)?

 

Thanks,

JB

Anonymous
Not applicable

Good question!

We have to assume that it is guranteed.

It's a risk, but it's a small one.

Anonymous
Not applicable

Thank you,

Mariusz has provided solution for this case :).

Kind regards
JB
Mariusz
Community Champion
Community Champion

Hi @Anonymous 

 

Try the below if it works for you 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUUpMLsksSwUyjJRidaKBJJKQIVjIGFnIDCxkgilkiixkDhYyA7I8/RydQzzDXIFMC7CgOaqgJVjQAsVWA7CYJRYxIIUmGAsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"EMPOLYEE ID" = _t, STATUS = _t, MANAGER = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"EMPOLYEE ID", Int64.Type}, {"STATUS", type text}, {"MANAGER", Int64.Type}}),
    #"Next Line Up Menager" = 
        let 
            #"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([STATUS] = "INACTIVE")),
            #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"MANAGER"}, #"Filtered Rows", {"EMPOLYEE ID"}, "Changed Type", JoinKind.LeftOuter)
        in
            #"Merged Queries",
    #"Expanded Changed Type" = Table.ExpandTableColumn(#"Next Line Up Menager", "Changed Type", {"MANAGER"}, {"Next Line Up Menager"})
in
    #"Expanded Changed Type"
Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
Mariusz Repczynski

 

Anonymous
Not applicable

Hi @Mariusz , I understand your solution and accept it, only question is, how do in change this code:

 Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUUpMLsksSwUyjJRidaKBJJKQIVjIGFnIDCxkgilkiixkDhYyA7I8/RydQzzDXIFMC7CgOaqgJVjQAsVWA7CYJRYxIIUmGAsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text

to capture my actual data? 

I suppose that  "BinaryFromText" was generated somehow, right?

Hi   

This is generated when you use the "Enter Data" functionality you don't need to worry about this bit.

All you need to do is a few extra steps in your table.

1. filter your table to All Inactive

2. Use Merge Queries 
image.png
On Current Table, with join on Manager and Employee ID
image.png
 

3.  Select Merged Queries Step from applied steps, go to the formula bar and replace #"Filtered Rows" with the step before.

image.png

 

4. last step is to expand your tables.

 

Hope this helps

Mariusz

@Anonymous

Anonymous
Not applicable

Hi all,

I need a little bit more help on this solution I do not understand what to replace.

This is the code I get when I do the following:

 

  1. FIlter all Inactive Employees
  2. Merge Queries
  3. Select "Manager" from the first table
  4. Select "Employee" from the second table

I do not know what do to do next 😞 , I am not sure how to read your steps when it comes to  <<Select Merged Queries Step from applied steps, go to the formula bar and replace #"Filtered Rows" with the step before>>

 

My code looks like this

   #"FILTERED INACTIVE" = Table.SelectRows(#"Cleaned Text", each ([STATUS] = "INACTIVE")),
    #"Merged Queries1" = Table.NestedJoin(#"FILTERED INACTIVE",{"MANAGER"},#"FILTERED INACTIVE",{"USERID"},"FILTERED INACTIVE",JoinKind.LeftOuter)

Am I reading something wrong from you steps?

Thanks

Luca

Hi @Anonymous 

 

Point 3 is suggesting to replace manually the first table expression ( step = #"FILTERED INACTIVE" ) with the one before in the Merge Step, please see the red circle on the screenshot from my previous post, 

 

If you still struggling, you can post your M from the Advanced Editor and I can do it for you.

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

 

Anonymous
Not applicable

Hello @Mariusz 

thank you so much for the clear help.

This key piece of training is extremely useful

I will now try your steps, but before I do I have a question,  about step 1: if I filter my table by Inactive before I merge, I have then to unfilter it afterwards , otherwise my final results will be wrong, or is this done in step 3 in your instructions?

 

thanks a mill!

Anonymous
Not applicable

Hi and thank you Mariusz.

 

Can you please expand a little bit on the propsed solution, from the code you pasted, I was trying to understnad where the actual "magic" happens, is it here?

 

Next Line Up Menager" = 
        let 
            #"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([STATUS] = "INACTIVE")),
            #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"MANAGER"}, #"Filtered Rows", {"EMPOLYEE ID"}, "Changed Type", JoinKind.LeftOuter)
        in
            #"Merged Queries",
    #"Expanded Changed Type" = Table.ExpandTableColumn(#"Next Line Up Menager", "Changed Type", {"MANAGER"}, {"Next Line Up Menager"})
in
    #"Expanded Changed Type"

 

 Are you performing a merge within the same query?

Anonymous
Not applicable

Hi @Anonymous

In PBI it is possible to encapsulate a section of code withing "let-in" group. In most cases it just makes the query look tidier in the editor.

In the code you have cited the bit relating to creating (filtering) a table that contains inactive employees and then merging it to the original table.

It is possible to re-write it to:
#"Filtered Rows" = Table.SelectRows(#"Changed Type", each ([STATUS] = "INACTIVE")),
#"Merged Queries" = Table.NestedJoin(#"Changed Type", {"MANAGER"}, #"Filtered Rows", {"EMPOLYEE ID"}, "Changed Type", JoinKind.LeftOuter),
#"Expanded Changed Type" = Table.ExpandTableColumn(#"Merged Queries", "Changed Type", {"MANAGER"}, {"Next Line Up Menager"})
in #"Expanded Changed Type"

Kind regards,
JB
Anonymous
Not applicable

Thank you @Anonymous , very clear.

I guess I now need one last "bit" of help with the code.

 

I have to adapt the "Table from Rows" to my current query, therefore the M code will have to be different.

I looked up the syntax of the function "Table.fromRows", but I cannot figure out how to tell PBI to select my entire current table and create the "sub-" table where the "Next Line Up Manager" data are created.

 

This section of the code below, is recreating the sample I have put in my first post, but I now need to use my real data.

Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUUpMLsksSwUyjJRidaKBJJKQIVjIGFnIDCxkgilkiixkDhYyA7I8/RydQzzDXIFMC7CgOaqgJVjQAsVWA7CYJRYxIIUmGAsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"EMPOLYEE ID" = _t, STATUS = _t, MANAGER = _t])

 

Thanks!

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

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.