Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Grouping items within a column

Hi,

 

My column: 'Card number'

It dispays various ways of payment.
I must group them into 3 separate groups:

 

1st Group:

CC-002

CC-00024

CC-00089787

and so on. All these various CC numbers need to be grouped together as "Card"

 

2nd Group:

Webpay1

Webpay2

VCWebpay

These three also need to be grouped as "WebPay"

3rd Group.

There are thousands of rows in that column that are all very different, e.g.:

CP678

B89789

EC-uiu-UK

KM8987ND7
176872554

and so on.
These must be grouped as "Members"

 

How can this be done? Is it DAX, SQL or R? 
I have looked everywhere. Not sure what to do. 
I hope someone will know how to approach this. 
Thank you kindly, 
J

4 ACCEPTED SOLUTIONS
Anonymous
Not applicable

Hi Poohkrd, 

Thank you very much. I do not know the M code well at this point, so before I start figuring out how I would insert your M to the existing code, please tell me what is the reason of listing the "CC-002", etc. in the first string? There are millions of variations and, for example, all these CC-002, CC-00024, CP678, B89789 are only a minuscule fraction of the number of variations that are in my Card Number column. 
It is not possible to list them all one by one. 

I need a solution that somehow groups ALL CC-(numbers), and all three WebPay Id's, and then whatever else as Members. 

Best,

J

View solution in original post

v-yanjiang-msft
Community Support
Community Support

Hi @Anonymous ,

You don't need to list any variation in the solution.  "CC-002" etc are listed in the first string is because it's automatically created string when you enter a table in Power BI.

What all you need to do is add a custom column in Power Query.

vkalyjmsft_0-1669359902814.png

Enter the code in the dialog:

if Text.StartsWith( [Card number], "CC", Comparer.OrdinalIgnoreCase ) 
            then "Card" 
            else if Text.Contains( [Card number], "WebPay", Comparer.OrdinalIgnoreCase ) 
                then "WebPay" 
                else "Members"

 

Or if you prefer DAX, create a new column.

vkalyjmsft_1-1669360173156.png

Column =
SWITCH (
    TRUE (),
    LEFT ( [Card number], 2 ) = "CC", "Card",
    CONTAINSSTRING ( [Card number], "Webpay" ), "WebPay",
    "Members"
)

Result:

vkalyjmsft_2-1669360510957.png

I attach my sample below for your reference, you can download it to see the details.

 

Best Regards,
Community Support Team _ kalyj

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

Hi @Anonymous ,

It's my pleasure! Tweak the formula to:

if Text.StartsWith( [Card number], "CC", Comparer.OrdinalIgnoreCase ) 
            then "Card" 
            else if Text.Contains( [Card number], "WebPay", Comparer.OrdinalIgnoreCase ) 
                then "WebPay" 
                else if List.Contains({"Remote Start","Engineer","Blank"},[Card number]) 
                  then [Card number] else "Members"

Get the correct result:

vkalyjmsft_0-1669370857406.png

Best Regards,
Community Support Team _ kalyj

View solution in original post

Hi @Anonymous ,

If the values are in italic in the right of the cell, I think it's because they are of number data type, try to click the left upper coner of the column and select "Text" before you add a custom column.

vkalyjmsft_1-1669601480001.png

Best Regards,
Community Support Team _ kalyj

View solution in original post

10 REPLIES 10
v-yanjiang-msft
Community Support
Community Support

Hi @Anonymous ,

You don't need to list any variation in the solution.  "CC-002" etc are listed in the first string is because it's automatically created string when you enter a table in Power BI.

What all you need to do is add a custom column in Power Query.

vkalyjmsft_0-1669359902814.png

Enter the code in the dialog:

if Text.StartsWith( [Card number], "CC", Comparer.OrdinalIgnoreCase ) 
            then "Card" 
            else if Text.Contains( [Card number], "WebPay", Comparer.OrdinalIgnoreCase ) 
                then "WebPay" 
                else "Members"

 

Or if you prefer DAX, create a new column.

vkalyjmsft_1-1669360173156.png

Column =
SWITCH (
    TRUE (),
    LEFT ( [Card number], 2 ) = "CC", "Card",
    CONTAINSSTRING ( [Card number], "Webpay" ), "WebPay",
    "Members"
)

Result:

vkalyjmsft_2-1669360510957.png

I attach my sample below for your reference, you can download it to see the details.

 

Best Regards,
Community Support Team _ kalyj

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Hi @v-yanjiang-msft 

Thank you so much. I love it. 

I've edited the code and all works fine, except: 
1). In my column some codes appear in italic, and these are giving me Errors. 
How can I change whatever is in italic not be in italic? I have approx 484 errors. 

See the pic below. All the errors are in some italic and appear on the right of my column, whereas everything else, that works, is placed on the left. 

it.PNG

 

2). There are also some (null) values that should stay null.

 

My code, that works is:

#"Added Custom" = Table.AddColumn(#"Removed Columns", "Custom 1", each if Text.StartsWith( [Card number], "CC", Comparer.OrdinalIgnoreCase )
then "Card"
else if Text.Contains( [Card number], "WebPay", Comparer.OrdinalIgnoreCase )
then "WebPay"
else if Text.Contains( [Card number], "Remote start", Comparer.OrdinalIgnoreCase )
then "Remote Start"
else if Text.Contains( [Card number], "Engineer", Comparer.OrdinalIgnoreCase )
then "Engineer"
else if Text.Contains( [Card number], "V0004001", Comparer.OrdinalIgnoreCase )
then "WebPay"
else if Text.Contains( [Card number], "(Blank)", Comparer.OrdinalIgnoreCase )
then "Blank"
else "Members")
in
#"Added Custom"

 

Please help me edit so the 2 additional arguments are added in. 

Your assistance as always highly appreciated. 

Thank you kindly, 

J

Hi @Anonymous ,

If the values are in italic in the right of the cell, I think it's because they are of number data type, try to click the left upper coner of the column and select "Text" before you add a custom column.

vkalyjmsft_1-1669601480001.png

Best Regards,
Community Support Team _ kalyj

Anonymous
Not applicable

 

Hi @v-yanjiang-msft 

Amazing, that works! Thank you so much. 

Best, 

Anonymous
Not applicable

 
 
 
 
 
Wow! Thank you so much @v-yanjiang-msft.
I love it! All the various solutions! Amazing!
I have already tested the Custom column and it worked magic!
Ok, so I haven't listed all the options.
 
 
 
 
Please tell me how can we add 3 additional items that are grouped already, and we must keep them as they are: Remote Start keep as "Remorte Start"
Engineer - as Engineer" 
(Blank) as "Blank"
Please kindly show me how to add these three to the one below:
 
if Text.StartsWith( [Card number], "CC", Comparer.OrdinalIgnoreCase ) 
            then "Card" 
            else if Text.Contains( [Card number], "WebPay", Comparer.OrdinalIgnoreCase ) 
                then "WebPay" 
                else "Members"
 
Thank you kindly. Much appreciation. 
J
 
 
 
 
 
 
 

Hi @Anonymous ,

It's my pleasure! Tweak the formula to:

if Text.StartsWith( [Card number], "CC", Comparer.OrdinalIgnoreCase ) 
            then "Card" 
            else if Text.Contains( [Card number], "WebPay", Comparer.OrdinalIgnoreCase ) 
                then "WebPay" 
                else if List.Contains({"Remote Start","Engineer","Blank"},[Card number]) 
                  then [Card number] else "Members"

Get the correct result:

vkalyjmsft_0-1669370857406.png

Best Regards,
Community Support Team _ kalyj

Anonymous
Not applicable

Hi @v-kalyj-msft

if Text.StartsWith( [Card number], "CC", Comparer.OrdinalIgnoreCase ) 
            then "Card" 
            else if Text.Contains( [Card number], "WebPay", Comparer.OrdinalIgnoreCase ) 
                then "WebPay" 
                else if List.Contains({"Remote Start","Engineer","Blank"},[Card number]) 
                  then [Card number] else "Members"

Actually the" Remote Start", "Engineer", "Blank" are not Card Number.
These are additional to CC and WebPay:
There should be all together 6 different payment variations:
CC- "Card"
WebPay "WebPay"

Remote Start "Remote Start"

Blank "Blank"

Engineer "Engineer"

else "Member"


I will really appreciate your edit to the code for me. 
Thank you. 

J

Anonymous
Not applicable

Hi kalyj, 

OMG! I love it! It woks! It's amazing! It makes me want to learn it! 
Thank you so very much. That's a huge help.

Best, J

Poohkrd
Advocate I
Advocate I

Hi, you want something like that?

 

let
    Source = Table.FromColumns( {{"CC-002","CC-00024","CC-00089787","Webpay1","Webpay2","VCWebpay","CP678","B89789","EC-uiu-UK","KM8987ND7","176872554"}}, {"Card number"} ),
    AddedGroup = Table.AddColumn(
        Source, 
        "Group", 
        each if Text.StartsWith( [Card number], "CC", Comparer.OrdinalIgnoreCase ) 
            then "Card" 
            else if Text.Contains( [Card number], "WebPay", Comparer.OrdinalIgnoreCase ) 
                then "WebPay" 
                else "Members"
    )
in
    AddedGroup

 

Anonymous
Not applicable

Hi Poohkrd, 

Thank you very much. I do not know the M code well at this point, so before I start figuring out how I would insert your M to the existing code, please tell me what is the reason of listing the "CC-002", etc. in the first string? There are millions of variations and, for example, all these CC-002, CC-00024, CP678, B89789 are only a minuscule fraction of the number of variations that are in my Card Number column. 
It is not possible to list them all one by one. 

I need a solution that somehow groups ALL CC-(numbers), and all three WebPay Id's, and then whatever else as Members. 

Best,

J

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors