Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
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 ID | STATUS | MANAGER |
| 1 | active | 2 |
| 2 | active | 1 |
| 3 | active | 6 |
| 4 | active | 6 |
| 5 | active | 7 |
| 6 | INACTIVE | 8 |
| 7 | INACTIVE | 9 |
| 8 | active | 10 |
| 9 | active | 10 |
| 10 | active | 10 |
Solved! Go to Solution.
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"
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
Good question!
We have to assume that it is guranteed.
It's a risk, but it's a small one.
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"
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 textto 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
On Current Table, with join on Manager and Employee ID
3. Select Merged Queries Step from applied steps, go to the formula bar and replace #"Filtered Rows" with the step before.
4. last step is to expand your tables.
Hope this helps
Mariusz
@Anonymous
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:
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.
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!
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?
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!
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
Check out the October 2025 Power BI update to learn about new features.