Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Hi All,
I want to search if the text of one column is existing in another column. Iferror then it returns a given text.
See excel formula below.
Thank you
Solved! Go to Solution.
You can do a merge
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcitKzEtOVdJRCi5PTUnNU4rViVbyLEnMqQQLZZZUpRblJOalgMXdU4tyE/NAMlBdIEFkRTpKoXmZJakpCt6Zeekp+blKsbEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Country = _t, Partner = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Country", type text}, {"Partner", type text}}),
#"Merged Queries" = Table.FuzzyNestedJoin(#"Changed Type", {"Partner"}, #"Changed Type", {"Country"}, "Changed Type", JoinKind.LeftOuter, [IgnoreCase=true, IgnoreSpace=true, NumberOfMatches=1, Threshold=1]),
#"Expanded Changed Type" = Table.ExpandTableColumn(#"Merged Queries", "Changed Type", {"Country"}, {"Changed Type.Country"}),
#"Replaced Value" = Table.ReplaceValue(#"Expanded Changed Type",null,"Missing",Replacer.ReplaceValue,{"Changed Type.Country"})
in
#"Replaced Value"
or use List.PositionOf
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcitKzEtOVdJRCi5PTUnNU4rViVbyLEnMqQQLZZZUpRblJOalgMXdU4tyE/NAMlBdIEFkRTpKoXmZJakpCt6Zeekp+blKsbEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Country = _t, Partner = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Country", type text}, {"Partner", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each try #"Changed Type"[Country]{List.PositionOf(#"Changed Type"[Country], [Partner])} otherwise "Missing")
in
#"Added Custom"
O
You can do a merge
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcitKzEtOVdJRCi5PTUnNU4rViVbyLEnMqQQLZZZUpRblJOalgMXdU4tyE/NAMlBdIEFkRTpKoXmZJakpCt6Zeekp+blKsbEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Country = _t, Partner = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Country", type text}, {"Partner", type text}}),
#"Merged Queries" = Table.FuzzyNestedJoin(#"Changed Type", {"Partner"}, #"Changed Type", {"Country"}, "Changed Type", JoinKind.LeftOuter, [IgnoreCase=true, IgnoreSpace=true, NumberOfMatches=1, Threshold=1]),
#"Expanded Changed Type" = Table.ExpandTableColumn(#"Merged Queries", "Changed Type", {"Country"}, {"Changed Type.Country"}),
#"Replaced Value" = Table.ReplaceValue(#"Expanded Changed Type",null,"Missing",Replacer.ReplaceValue,{"Changed Type.Country"})
in
#"Replaced Value"
or use List.PositionOf
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcitKzEtOVdJRCi5PTUnNU4rViVbyLEnMqQQLZZZUpRblJOalgMXdU4tyE/NAMlBdIEFkRTpKoXmZJakpCt6Zeekp+blKsbEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Country = _t, Partner = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Country", type text}, {"Partner", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each try #"Changed Type"[Country]{List.PositionOf(#"Changed Type"[Country], [Partner])} otherwise "Missing")
in
#"Added Custom"
O
Thanks Latimera works well!
Sorry I forgot to mention I want to do it directly in power Query. If not possible then using DAX formula. Thank you
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
29 | |
26 | |
16 | |
12 | |
10 |
User | Count |
---|---|
28 | |
24 | |
22 | |
16 | |
12 |