March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hi guys,
I am totally new to Power BI, the Power Query Editor and most of all the M language. I wanna try to import data from different Excel documents using the Power Query Editor and then merge different columns from these separate documents using the joins function. Finally, I plan to add another custom column to this merged table with a formula that refers to a sheet in another Excel document. My main difficulty for now is that I am not able to "translate" the following formula into the M language:
=IFNA(VLOOKUP(A2,'Implementing Organisations'!A2:B6, 2,FALSE), "unassignable")
Under the following link you can find a dummy Excel document, which basically shows what I am trying to do with the custom column function in the Power Query Editor (once I have managed to merge the two columns from the other Excel docs): https://drive.google.com/file/d/1lkfFzK7vszkuLBdVcQdG6mNyy0JJv5iP/view?usp=sharing. You can see that the Excel workbook contains two different worksheets: The first one is titled "Sample data" and it contains the above-mentioned formula in column B. The formula compares the spelling of the organisations in column A with a pre-defined list of deviating and obligatory spellings in the worksheet "Implementing Organisations" - if the name of the organisation is incomplete the formula will automatically complete/correct the spelling of the name (provided that the correct name of the organisations is included in the list in the "Implementing Organisations" worksheet). Now here's my actual question: Could someone of you please explain to me how I could add a custom column with the this formula into my table in the Power Query Editor (see screenshot below)? I believe that my main difficulties are that in the M language there does not exist a function such as the IFNA function and that the formula refers to another Excel worksheet ("Implementing Organisations"), which is not part of the current query that I have created...
I look forward to your answers and want to thank you in advance for your help! 🙂
Best,
lasse0hlsen
Solved! Go to Solution.
Hello @lasse0hlsen
for IFNA and VLOOKUP you can use a Table.NestedJoin and adding a new column checking if its empty. If it's empty "not assignable" is return else the first value found. Here the complete solution
let
SourceA =
let
Source = #table
(
{"ColumnA"},
{
{"A"}, {"B"}, {"A"}, {"A"}, {"A"}, {"C"}
}
)
in
Source,
SourceB =
let
Source = #table
(
{"ColumnA","ColumnB"},
{
{"A","ValueA1"}, {"A","ValueA2"}, {"B","ValueB1"}
}
)
in
Source,
Join = Table.NestedJoin
(
SourceA,
"ColumnA",
SourceB,
"ColumnA",
"SourceB"
),
Final= Table.AddColumn
(
Join,
"ResultJoin", //get first data ColumnB and if empty "unassignable"
each if Table.IsEmpty(_[SourceB]) then "unassignable" else Table.First(_[SourceB])[ColumnB]
),
RemoveColumns = Table.RemoveColumns(Final,{"SourceB"})
in
RemoveColumns
Copy paste this code to the advanced editor in a new blank query to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
Hello @lasse0hlsen
have you been able to solve the problem with the replies given?
If so, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
All the best
Jimmy
Hello @lasse0hlsen
for IFNA and VLOOKUP you can use a Table.NestedJoin and adding a new column checking if its empty. If it's empty "not assignable" is return else the first value found. Here the complete solution
let
SourceA =
let
Source = #table
(
{"ColumnA"},
{
{"A"}, {"B"}, {"A"}, {"A"}, {"A"}, {"C"}
}
)
in
Source,
SourceB =
let
Source = #table
(
{"ColumnA","ColumnB"},
{
{"A","ValueA1"}, {"A","ValueA2"}, {"B","ValueB1"}
}
)
in
Source,
Join = Table.NestedJoin
(
SourceA,
"ColumnA",
SourceB,
"ColumnA",
"SourceB"
),
Final= Table.AddColumn
(
Join,
"ResultJoin", //get first data ColumnB and if empty "unassignable"
each if Table.IsEmpty(_[SourceB]) then "unassignable" else Table.First(_[SourceB])[ColumnB]
),
RemoveColumns = Table.RemoveColumns(Final,{"SourceB"})
in
RemoveColumns
Copy paste this code to the advanced editor in a new blank query to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
Many thanks, Jimmy! That did the trick! 🙂
Cheers,
Lasse
A vlookup is pretty similar to the "Merge Queries" button. Give that a go and see if you can join the data.
Unlike a Vlookup, this join will let you bring in multiple columns from your found result.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.