Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hello everyone,
I´ve been working around but i don´t have enought M knowledge.
I want to categorize some of my products depending on which text they contains. Until here i am doing that with the conditional feature of PowerQuery (same as If). But at the end it works as a table of two columns where if you find A give me B.
My question es , can i do that with Power query and one table in Excel? It would be really helpful because if i can do that i can give the hability of categorization to my end user.
Thank you in advance!!
Solved! Go to Solution.
If I interpret your information correctly, you want to use a lookup table.
After Table1 and table Categories are loaded in Power Query (connection only), the following query adds a column to table Table1 with the category from table Categories:
let Source = Table1, #"Added Custom" = Table.AddColumn(Source, "Category", (x) => Text.Combine(Table.SelectRows(Categories, each Text.Contains(x[SomeText],[TextPart],Comparer.OrdinalIgnoreCase))[Category],", ")) in #"Added Custom"
The texts are compared case-insensitive; in case a text contains multiple TextParts, it will get all associated categories,
Examples:
No Category found for Sean.
You can extend the formula with List.Distinct.
let Source = Table1, #"Added Custom" = Table.AddColumn(Source, "Category", (x) => Text.Combine(List.Distinct(Table.SelectRows(Categories, each Text.Contains(x[SomeText],[TextPart],Comparer.OrdinalIgnoreCase))[Category]),", ")) in #"Added Custom"
Remark: the close parenthesis for List.Distinct is behind "[Category]"
If I interpret your information correctly, you want to use a lookup table.
After Table1 and table Categories are loaded in Power Query (connection only), the following query adds a column to table Table1 with the category from table Categories:
let Source = Table1, #"Added Custom" = Table.AddColumn(Source, "Category", (x) => Text.Combine(Table.SelectRows(Categories, each Text.Contains(x[SomeText],[TextPart],Comparer.OrdinalIgnoreCase))[Category],", ")) in #"Added Custom"
The texts are compared case-insensitive; in case a text contains multiple TextParts, it will get all associated categories,
Examples:
No Category found for Sean.
Hello MarcelBeug,
Everything works perfect, it helps me to avoid a lot of manual stuff...
I have one more question about it. I want to avoid the ones which the categorization is duplicated. I have several Key_Words for each category and sometimes they have more than one.
I.e: Neobaron is categorized as Visitor, Visitor. is there any way to avoid that? For the ones that the categorization is different is fine, but i want to avoid the ones those are duplicated. .
Again thank you,
You can extend the formula with List.Distinct.
let Source = Table1, #"Added Custom" = Table.AddColumn(Source, "Category", (x) => Text.Combine(List.Distinct(Table.SelectRows(Categories, each Text.Contains(x[SomeText],[TextPart],Comparer.OrdinalIgnoreCase))[Category]),", ")) in #"Added Custom"
Remark: the close parenthesis for List.Distinct is behind "[Category]"
You are genius!!!!
And your remark was great too
Thank you very much!! It is perfect, i will try to modify your code to add it directly to table one. And your coderis better because i am getting more categories than one. I bought M is for Data Monkey. do you know where i could learn more about M? Thank you in advance!
User | Count |
---|---|
61 | |
59 | |
56 | |
38 | |
29 |
User | Count |
---|---|
82 | |
62 | |
45 | |
41 | |
40 |