Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.
Check it out now!Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers. Get Fabric certified for FREE! Learn more
Hello,
I have a situation where I need to perform a lookup, but the search value column (Tester ID(s)) sometimes has more than one value that is pipe-delimited. In my example below, is it possible to perform a lookup that returns a concatened list of all matched names from the "Name Column" of the UserInfoTable based on the match between the two ID columns?
Tester ID(s) | Matched Tester Name(s) |
344|465 | Bob, Sue |
1353 | |
334|17687 | |
389 |
UserInfoTable
ID | Name |
334 | Bob |
344 | Tim |
389 | Joe |
465 | Sue |
17687 | Betty |
I have tried a few options like the function below; however, it will return a blank result for any Tester ID row where there is more than one value.
Matched Tester Name = VAR IDList = SUBSTITUTE(Tester ID(s), "|", ",") RETURN CONCATENATEX( FILTER( 'UserInfoTable', CONTAINSROW( {IDList}, 'UserInfoTable'[ID] ) ), 'UserInfoTable'[Name], "|" )
Thank you
Solved! Go to Solution.
Hi @LSDJAX ,
Consider also using M for this:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjYxqTExM1WK1YlWMjQ2NQYzjI1NagzNzSzMITwLS6XYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Tester ID(s)" = _t]),
#"Added Custom" = Table.AddColumn(Source, "ID", each Text.Split([#"Tester ID(s)"], "|")),
#"Expanded ID" = Table.ExpandListColumn(#"Added Custom", "ID"),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded ID", {{"ID", Int64.Type}}),
#"Merged Queries" = Table.NestedJoin(#"Changed Type1", {"ID"}, UserInfoTable, {"ID"}, "UserInfoTable", JoinKind.LeftOuter),
#"Expanded UserInfoTable" = Table.ExpandTableColumn(#"Merged Queries", "UserInfoTable", {"Name"}, {"Name"}),
#"Grouped Rows" = Table.Group(#"Expanded UserInfoTable", {"Tester ID(s)"}, {{"Matched Tester Name(s)", each Text.Combine([Name], ",")}})
in
#"Grouped Rows"
A sample file is attached for reference.
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum -- China Power BI User Group
Hi @LSDJAX, different approach:
Result
let
TestersTable = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjYxqTExM1WK1YlWMjQ2NQYzjI1NagzNzSzMITwLS6XYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Tester ID(s)" = _t]),
UserInfoTable = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjY2UdJRcspPUorVAfJMQLyQzFwIz8ISyPPKTwXzTMxMgbzgUgjP0NzMwhykM7WkpFIpNhYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t]),
BufferedUserInfo = Table.Buffer(UserInfoTable),
Ad_MatchedTesterNames = Table.AddColumn(TestersTable, "Matched Tester Name(s)", each
[ a = Text.Split([#"Tester ID(s)"], "|"),
b = List.Combine(List.Transform(a, (x)=> Table.SelectRows(BufferedUserInfo, (y)=> y[ID] = x)[Name])),
c = if List.IsEmpty(b) then null else Text.Combine(b, ", ")
][c], type text)
in
Ad_MatchedTesterNames
Hi @LSDJAX, different approach:
Result
let
TestersTable = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjYxqTExM1WK1YlWMjQ2NQYzjI1NagzNzSzMITwLS6XYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Tester ID(s)" = _t]),
UserInfoTable = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjY2UdJRcspPUorVAfJMQLyQzFwIz8ISyPPKTwXzTMxMgbzgUgjP0NzMwhykM7WkpFIpNhYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t]),
BufferedUserInfo = Table.Buffer(UserInfoTable),
Ad_MatchedTesterNames = Table.AddColumn(TestersTable, "Matched Tester Name(s)", each
[ a = Text.Split([#"Tester ID(s)"], "|"),
b = List.Combine(List.Transform(a, (x)=> Table.SelectRows(BufferedUserInfo, (y)=> y[ID] = x)[Name])),
c = if List.IsEmpty(b) then null else Text.Combine(b, ", ")
][c], type text)
in
Ad_MatchedTesterNames
Hi @LSDJAX ,
Consider also using M for this:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjYxqTExM1WK1YlWMjQ2NQYzjI1NagzNzSzMITwLS6XYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Tester ID(s)" = _t]),
#"Added Custom" = Table.AddColumn(Source, "ID", each Text.Split([#"Tester ID(s)"], "|")),
#"Expanded ID" = Table.ExpandListColumn(#"Added Custom", "ID"),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded ID", {{"ID", Int64.Type}}),
#"Merged Queries" = Table.NestedJoin(#"Changed Type1", {"ID"}, UserInfoTable, {"ID"}, "UserInfoTable", JoinKind.LeftOuter),
#"Expanded UserInfoTable" = Table.ExpandTableColumn(#"Merged Queries", "UserInfoTable", {"Name"}, {"Name"}),
#"Grouped Rows" = Table.Group(#"Expanded UserInfoTable", {"Tester ID(s)"}, {{"Matched Tester Name(s)", each Text.Combine([Name], ",")}})
in
#"Grouped Rows"
A sample file is attached for reference.
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum -- China Power BI User Group
Thank you so much for the test file. I was able to follow your applied steps and duplicate the steps in my source file to reach the desired result.
Something like this should work in a measure:
Tester Name(s) =
VAR _Delim = "|"
VAR _Parser = "☃"
VAR _CurrentIDs = SELECTEDVALUE( Tests[Tester ID(s)])
VAR _DelimCount = LEN( _CurrentIDs ) - LEN( SUBSTITUTE( _CurrentIDs, _Delim, "" ) )
VAR _SequenceGen = GENERATESERIES( 1, _DelimCount + 1, 1 )
VAR _LookupNames =
GENERATE(
_SequenceGen,
VAR _i = [Value]
VAR _start = IF( _i = 1, 0, FIND( _Parser, SUBSTITUTE( _CurrentIDs & _Delim, _Delim, _Parser, _i - 1 ) ) )
VAR _end = FIND( _Parser, SUBSTITUTE( _CurrentIDs & _Delim, _Delim, _Parser, _i ) )
VAR _TesterId = VALUE( MID( _CurrentIDs, _start + 1, _end - _start - 1 ) )
RETURN
ROW( "TesterName", LOOKUPVALUE( UserInfoTable[Name], UserInfoTable[ID], _TesterId ) )
)
RETURN
CONCATENATEX( _LookupNames, [TesterName], ", " )
Result:
I'll add that if it were me, I would probably look to model this better.
E.g. Tests -1----M-> TestsUsers <-M----1- UserInfoTable
where TestUsers would be the fact table of Test,Users pairings:
TestID | UserID |
1 | 344 |
1 | 465 |
2 | 1353 |
3 | 334 |
3 | 17687 |
4 | 389 |