Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
Hi and thanks for reading this.
i have looked around and i cant seem to find any answer for my problem
not sure how easy or hard this is , have only been able to get true /false check to work 🙂
i have two tables , Table1 and Table2
i would like to create a new column in Table1 where i check the statements.
If Table1[ID] = Table2[ID] && Table1[Value] >= Tabel2[Check1] && Table1[Value] <= Table2[Check2] then Table2[Return]
also if error or not match at all it gives "Not found"
Someting like this:
Thanks so much for any help to point me in the right direction
Solved! Go to Solution.
Use this formula
let
T1=Table.FromColumns({{1..5},{10,11,12,13,22}},{"ID","Value"}),
T2=Table.FromColumns({{1,2,3,4,2},{5,6,11,1,7},{10,10,22,14,12},{"Green","BLue","BRown","Yellow","Red"}},{"ID","Check 1","Check 2","Return"}),
#"Added Custom" = Table.AddColumn(T1, "Custom", each try Table.SelectRows(T2, (x)=> x[ID]=_[ID] and x[Check 1]<=_[Value] and x[Check 2]>=_[Value])[Return]{0} otherwise "Not Found")
in
#"Added Custom"
For more descrition see this video:
https://www.youtube.com/watch?v=DHB2ejpEGxU
Use this formula
let
T1=Table.FromColumns({{1..5},{10,11,12,13,22}},{"ID","Value"}),
T2=Table.FromColumns({{1,2,3,4,2},{5,6,11,1,7},{10,10,22,14,12},{"Green","BLue","BRown","Yellow","Red"}},{"ID","Check 1","Check 2","Return"}),
#"Added Custom" = Table.AddColumn(T1, "Custom", each try Table.SelectRows(T2, (x)=> x[ID]=_[ID] and x[Check 1]<=_[Value] and x[Check 2]>=_[Value])[Return]{0} otherwise "Not Found")
in
#"Added Custom"
For more descrition see this video:
https://www.youtube.com/watch?v=DHB2ejpEGxU
Hi @Omid_Motamedise and @Claude_Xu
Thanks Both for the help here . Really appriciate it 🙂
You are welcome
@Omid_Motamedise
I see that this is not working when i have a Direct Query .Get an error that says that its not supported in DirectQ.
Is it possible to do this in Direct Q ??
The Fact table is important and the Table1 is a Direct Q
/Thanks
Check this code, (it results in recodr, but just let me know does it work in Direct Query)
let
T1=Table.FromColumns({{1..5},{10,11,12,13,22}},{"ID","Value"}),
T2=Table.FromColumns({{1,2,3,4,2},{5,6,11,1,7},{10,10,22,14,12},{"Green","BLue","BRown","Yellow","Red"}},{"ID","Check 1","Check 2","Return"}),
#"Added Custom" = Table.First(Table.AddColumn(T1, "Custom", each Table.SelectRows(T2, (x)=> x[ID]=_[ID] and x[Check 1]<=_[Value] and x[Check 2]>=_[Value])) )
in
#"Added Custom"
Hi @Omid_Motamedise
it gives me someting strange Record Tools lights up 🙂
But not the error as before
Yes, it is not complete and need to add another part including Record.Field, but I am wondering until this step, does it align with the direct query?
I get no errors, The table is not column Left to right , its Top to botton instead
So, now check the below codes and let me know which one does work on direct query.
S1:
let
T1=Table.FromColumns({{1..5},{10,11,12,13,22}},{"ID","Value"}),
T2=Table.FromColumns({{1,2,3,4,2},{5,6,11,1,7},{10,10,22,14,12},{"Green","BLue","BRown","Yellow","Red"}},{"ID","Check 1","Check 2","Return"}),
#"Added Custom" = Table.AddColumn(T1, "Custom", each Table.First(Table.SelectRows(T2, (x)=> x[ID]=_[ID] and x[Check 1]<=_[Value] and x[Check 2]>=_[Value]))[Return])
in
#"Added Custom"
S2:
let
T1=Table.FromColumns({{1..5},{10,11,12,13,22}},{"ID","Value"}),
T2=Table.FromColumns({{1,2,3,4,2},{5,6,11,1,7},{10,10,22,14,12},{"Green","BLue","BRown","Yellow","Red"}},{"ID","Check 1","Check 2","Return"}),
#"Added Custom" = Table.AddColumn(T1, "Custom", each Record.Field(Table.First(Table.SelectRows(T2, (x)=> x[ID]=_[ID] and x[Check 1]<=_[Value] and x[Check 2]>=_[Value])),"Return"))
in
#"Added Custom"
S3:
let
T1=Table.FromColumns({{1..5},{10,11,12,13,22}},{"ID","Value"}),
T2=Table.FromColumns({{1,2,3,4,2},{5,6,11,1,7},{10,10,22,14,12},{"Green","BLue","BRown","Yellow","Red"}},{"ID","Check 1","Check 2","Return"}),
#"Added Custom" = Table.AddColumn(T1, "Custom", each List.First(Table.Column(Table.SelectRows(T2, (x)=> x[ID]=_[ID] and x[Check 1]<=_[Value] and x[Check 2]>=_[Value]),"Return")))
in
#"Added Custom"
S4:
let
T1=Table.FromColumns({{1..5},{10,11,12,13,22}},{"ID","Value"}),
T2=Table.FromColumns({{1,2,3,4,2},{5,6,11,1,7},{10,10,22,14,12},{"Green","BLue","BRown","Yellow","Red"}},{"ID","Check 1","Check 2","Return"}),
#"Added Custom" = Table.AddColumn(T1, "Custom", each Table.Column(Table.SelectRows(T2, (x)=> x[ID]=_[ID] and x[Check 1]<=_[Value] and x[Check 2]>=_[Value]),"Return"){0})
in
#"Added Custom"
Hi @Omid_Motamedise
First thx so much for helping me out there.
this is what i got :
S1 get Error in the custom and Not supported in DirectQ
S2 get Error in the custom and Not supported in DirectQ
S3 Get Null in Custom and Not supported in DirectQ
S4 Get Null in Custom and Not supported in DirectQ
/Thanks
Hi Wresen,
Please refer to below implementation
let
Table1 = #table({"ID", "Value"}, {
{1,10},
{2,11},
{3,12},
{4,13},
{5,22},
{2,8}
}),
Table2 = #table({"id", "Check1", "Check2", "Return"},{
{1,5,10,"Green"},
{2,6,10,"Blue"},
{3,11,22,"Brown"},
{4,1,14,"Yellow"},
{2,7,12,"Red"}
}),
#"Left Join Table" = Table.Join(Table1, "ID", Table2, "id", JoinKind.LeftOuter),
#"Add Custom Column" = Table.AddColumn(#"Left Join Table", "Custom",
each try if [Value] >= [Check1] and [Value] <= [Check2] then [Return]
else "Not Found"
otherwise "Not Found"
),
Result = Table.Group(#"Add Custom Column", {"ID", "Value"},{
{"Custom", each if Table.RowCount(_) = 1 then [Custom]{0}
else Text.Combine(List.RemoveItems([Custom], {"Not Found"}), ", ")}
})
in
Result
It seems you did not mention the logic of some edge cases. For example, if you have [ID=2, Value=8] in Table1, there will be two matching records in Table2. The above implementation simply joins two matching 'Return' string literals with a comma.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
14 | |
13 | |
12 | |
12 | |
12 |