• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

search text or phrases from a string in Table A and match with another list and return the values|Power Query|Excel Forum|My Online Training Hub

You are here: Home / search text or phrases from a string in Table A and match with another list and return the values|Power Query|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumPower Querysearch text or phrases from a strin…
sp_PrintTopic sp_TopicIcon
search text or phrases from a string in Table A and match with another list and return the values
Page: 12Jump to page
Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
1
November 11, 2019 - 4:36 pm
sp_Permalink sp_Print

Hi Power Query Guru

See attached,   is there a way to search text or phrases from another List and return the values 

 

in excel need to use

=IFERROR(LOOKUP(2^15,SEARCH('Contents Lib'!$A$2:$A$8,A2),'Contents Lib'!$B$2:$B$8),"")

and is tedious

 

thank you 

sp_AnswersTopicSeeAnswer See Answer
Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4449
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
2
November 11, 2019 - 9:47 pm
sp_Permalink sp_Print

Hi Chris,

Yes, you can extract the camp from the text string and then use Merge Tables to bring in the Region column. See example attached.

Mynda

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
3
November 12, 2019 - 2:28 pm
sp_Permalink sp_Print

Hi Mynda,

Thanks,  this is for delimited that are consistent throughout 

in my real case scenario,  the description can be free form see attached (illustration)

is there a equivalent excel array in Power Query or there are other simple way (using M language)

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
4
November 12, 2019 - 2:42 pm
sp_Permalink sp_Print sp_EditHistory

Hi Mynda,

what version of excel you are using

= Table.AddColumn(#"Changed Type", "Text Between Delimiters", each Text.BetweenDelimiters([Folder path], "/", "/", 2, 0), type text)

my excel 2016 don't have the Text Between Delimiters option,  mine office is professional plus 2016

Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4449
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
5
November 12, 2019 - 4:26 pm
sp_Permalink sp_Print

Hi Chris,

I'm using Office 365. You can try updating your version of Excel to see if you get the new functions.

In regards to your messy data. Even with formulas there are limits. CampAB without a space will not be found because it doesn't exist in your Camp Regions table.

For the other data, you could split it by 'Camp' as the delimiter and then remove the text after the last forward slash and the .... and then do a merge on the Camp name. It's all possible, except for the CampAB without the space.

Mynda

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
6
November 12, 2019 - 4:59 pm
sp_Permalink sp_Print

Hi Mynda,

Actually,  the actual datasets are proj description and was trying to do text analytics, and there is a table (List) that store all the translation,  for e.g. if Camp A - Fleet Department

In the past I use combination of few excel commands

=IFERROR(LOOKUP(2^15,SEARCH('Contents Lib'!$A$2:$A$8,A2),'Contents Lib'!$B$2:$B$8),"")

 

$A$2:$A$8 = Camp AA,  Camp BB .....    (this one will grow)

$B$2:$B$8 = 2nd column that returning back for analysis

Therefore,  I was wondering is there a better way to use M language combine with PQ editor features to ease user's experience haha,  as for using delimiter need to build a lot of scenario as we wouldn't know the pattern of the data input from users (free play), those are legacy system fields

Thank you

Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4449
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
7
November 12, 2019 - 9:07 pm
sp_Permalink sp_Print

This thread might give you some ideas. You'll still need to fix any data that doesn't conform to your list e.g. CampAB without the space.

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
8
November 12, 2019 - 10:12 pm
sp_Permalink sp_Print sp_EditHistory

Hi Chris,

You can transform the lookup table query into a function, after adding a new column to check for a match on each row.

Note that there cannot be perfect matches, as for example //Level 1/Camp ABC/Bunk can match with Camp ABC -region A but also with Camp AB-region C.

The solution from the attached file will take only the first match in such cases.

You might be able to deal with such cases if your lookup table contains values in this format:

/Camp ABC/

/Camp AB/

sp_AnswersTopicAnswer
Answers Post
Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
9
November 14, 2019 - 12:48 pm
sp_Permalink sp_Print sp_EditHistory

thank you so much Mynda for your tips

as for the CampAB without space,  user will need to constantly update their library

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
10
November 14, 2019 - 12:50 pm
sp_Permalink sp_Print sp_EditHistory

Thank you so much Catalin,  this is the first time I see function and parameter in PQ,   after adding CampAB = C and refresh it returns correctly,  amazing !!!

Can I confirm your function will look out any key words, phrases in the matching table and return column 2 for any form of verbatim texts

 

Thank you !!

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
11
November 14, 2019 - 1:51 pm
sp_Permalink sp_Print sp_EditHistory

Well, that's what your test just did, if the keyword is in lookup table, there will be a value return,  it will display null if no match found.

It is case sensitive, so you have to be careful with text case, or make the query case insensitive to make it work with "Camp AB" and "camp ab" as well.

As mentioned before, if there are multiple matches, only the first will be returned. It is possible though to return a list of all matches in this case, like "A, C, D" if there are 3 matches for example.

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
12
November 14, 2019 - 2:44 pm
sp_Permalink sp_Print

Hi Catalin

for the match function,  you are using Advanced editor to input M code directly right,  or UI ?

= (Text)=>
let
Source = Excel.CurrentWorkbook(){[Name="Table2"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Camp", type text}, {"Region", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Match", each Text.Contains(Text,[Camp])),
#"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Match] <> false)),
#"Removed Other Columns" = try Table.SelectColumns(#"Filtered Rows",{"Region"}){0} otherwise null
in
#"Removed Other Columns"

which line should I amend if I want to expand my table 2 to include other keywords other than Camp **

and each time we entered an invalid text it will involve the result in the query listing,  can we just display out it is null at the preview area ?

 

Sorry to ask so many questions,  all along i was no good in coding   🙁

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
13
November 14, 2019 - 7:23 pm
sp_Permalink sp_Print sp_EditHistory

First, I add the lookup table as a query, just like any other table, ad I perform the operations I need to get the result I need: added a column with a simple formula to check if my custom text is in the Camp column, filter out false matches, remove other columns than "Region".

Only at this point I open the advanced editor, find below in red the only changes I made to convert the query to a function that takes a text variable:

(Text)=>
let
Source = Excel.CurrentWorkbook(){[Name="Table2"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Camp", type text}, {"Region", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Match", each Text.Contains(Text,[Camp])),
#"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Match] <> false)),
#"Removed Other Columns" = try Table.SelectColumns(#"Filtered Rows",{"Region"}){0} otherwise null
in
#"Removed Other Columns"

The (Text)=> part is what makes it a function, you just need to place that above the existing query.

 

To add more keywords, just add them to the lookup table from sheet, there is nothing else you need to do in query, it will just read the updated table.

The rows with no match will display null in both query editor and result table.

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
14
November 14, 2019 - 11:18 pm
sp_Permalink sp_Print

Hi catalin,

so each time I append new phrases and the result,   the function code will automatically update right ?

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
15
November 15, 2019 - 12:58 am
sp_Permalink sp_Print

Yes.

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
16
November 15, 2019 - 5:11 pm
sp_Permalink sp_Print

Catalin,

How about the questions on not showing the invoked function in the queries list ?  that is under the Text (optional) enter a text then click involve,   it will generate a query in the query listing,  I do not want PQ to generate, is it possible

and for this function,  is zit possible to search multiple and return multiple results

for e.g.  //Level/Camp CC/Tuckshop

the lookup table Camp CC = C,  Tuckshop = Canteen

the result will be

//Level/Camp CC/Tuckshop              D

//Level/Camp CC/Tuckshop              Canteen

 

See attached

 

Thank you !

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
17
November 15, 2019 - 6:30 pm
sp_Permalink sp_Print

Catalin Bombea said
First, I add the lookup table as a query, just like any other table, ad I perform the operations I need to get the result I need: added a column with a simple formula to check if my custom text is in the Camp column, filter out false matches, remove other columns than "Region".

Only at this point I open the advanced editor, find below in red the only changes I made to convert the query to a function that takes a text variable:

<br />
<span style="color: #ff0000;"> (Text)=&gt;</span><br />
let<br />
Source = Excel.CurrentWorkbook(){[Name="Table2"]}[Content],<br />
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Camp", type text}, {"Region", type text}}),<br />
#"Added Custom" = Table.AddColumn(#"Changed Type", "Match", each Text.Contains(<span style="color: #ff0000;">Text</span>,[Camp])),<br />
#"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Match] &lt;&gt; false)),<br />
#"Removed Other Columns" = <span style="color: #ff0000;">try</span> Table.SelectColumns(#"Filtered Rows",{"Region"})<span style="color: #ff0000;">{0} otherwise null</span><br />
in<br />
#"Removed Other Columns"<br />
<br />

The (Text)=> part is what makes it a function, you just need to place that above the existing query.

To add more keywords, just add them to the lookup table from sheet, there is nothing else you need to do in query, it will just read the updated table.

The rows with no match will display null in both query editor and result table.  

what is the original word for Text (highlighted in red) ?  I am trying to understand your code from #Added custom to Removed other columns,  you mentioned you use the Power query UI

or can you provide me the original code before amending to function i.e.  replace add code (those in red)

Thank you

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
18
November 15, 2019 - 11:14 pm
sp_Permalink sp_Print sp_EditHistory

If you want to have multiple matches, remove the {0} from the function, this is what refers to the first match only.

 

When you work on the lookup table, you can use any text you want to add the custom column.

You can use any static text you want, "Camp AB" for example:

#"Added Custom" = Table.AddColumn(#"Changed Type", "Match", each Text.Contains("Camp AB",[Camp])),

 

Then, after you're done with the processing, add the parameter you want above the first line of the query:

(ParameterName)=>

and replace "Camp AB" with ParameterName.

I used Text as parameter name.

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
19
November 15, 2019 - 11:47 pm
sp_Permalink sp_Print

Hi Catalin

but when I remove the {0},   all shown error

Avatar
Chris Yap
Member
Members
Level 0
Forum Posts: 162
Member Since:
August 21, 2019
sp_UserOfflineSmall Offline
20
November 15, 2019 - 11:51 pm
sp_Permalink sp_Print

Hi Catalin,

Attached,  how to return in this format, possible ?

Description of text verbatim Region
//Level 1/Camp ABC/Bunk A
//Level 1/Camp DD/Tuckshop D
//Level 1/Camp DD/Tuckshop Canteen
There is a pipe burst in Camp BB B
d:\folder1\Camp\CampAB C
-----------   Camp CC ……………….. D
Page: 12Jump to page
sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: andria young, Bruce Tang Nian
Guest(s) 11
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 871
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
Jessica Stewart: 205
A.Maurizio: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
Bruce Tang Nian
Scot C
Othman AL MUTAIRI
Misael Gutierrez Sr.
Attif Ihsan
Kieran Fee
Murat Hasanoglu
Brett Dryland
Saeed Aldousari
Bhuwan Devkota
Forum Stats:
Groups: 3
Forums: 24
Topics: 6222
Posts: 27293

 

Member Stats:
Guest Posters: 49
Members: 31918
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.