cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
cmengel
Frequent Visitor

Use Text.StartsWith and List.Contains to efficiently build custom columns

Hi!

 

Has anyone figured out the best way to use List.Contains in combo with Text.StartsWith in PowerQuery?

 

I create custom Y/N columns in PQ to make my DAX measures easier to write by filtering on these columns.

 

Recent example:

#"AddedEXPENSE" =
        Table.AddColumn(
            AddedALLOWED,
            "EXPENSE",
            each
                if
        //  Explicitly define EXPENSE codes
                    List.Contains(
                        {
                            "3L",
                            "3K",
                            "3O",
                            // letter "oh" NOT ZERO!!!
                            "3A",
                            "3E",
                            "3G",
                            "3B",
                            "3F",
                            "3M",
                            "3S",
                            "3J",
                            "3H"
                        },
                        [WO_LABOR_CLASS_CODE]
                    )
                then
                    "Y"
        //  Explicitly define NON-EXPENSE codes
                else if
                List.Contains(
                        {
                            "3C",
                            "3I",
                            "3V",
                            "3P",
                            "3Q",
                            "3N",
                            "3W",
                            "3X"
                        },
                        [WO_LABOR_CLASS_CODE]
                    )
                    or
                    Text.StartsWith(
                        [WO_LABOR_CLASS_CODE],
                        "A"
                    )
                    or
                    Text.StartsWith(
                        [WO_LABOR_CLASS_CODE],
                        "B"
                    )
                    or
                    Text.StartsWith(
                        [WO_LABOR_CLASS_CODE],
                        "C"
                    )
                    or
                    Text.StartsWith(
                        [WO_LABOR_CLASS_CODE],
                        "1"
                    )
                    or
                    Text.StartsWith(
                        [WO_LABOR_CLASS_CODE],
                        "2"
                    )
                then
                    "N"
                else if
                    [WO_LABOR_CLASS_CODE] = "NON_LABOR" then
                    "N"
        //  Catch items that are not explicitly defined or mapped
                else
                    "CLARIFY",
            type text
        ),
 
Notice how the first clause uses the List.Contains function.  I like this function a lot - easier to write, read, test, maintain, etc.
 
The second clause is more verbose and terribly inefficient to write, read, process, etc.
 
My objective is to write the second clause in such a way that I can use the Text.StartsWith function and provide a List.Contains function.  I think it'll speed up my query (and shorten it!).
 
I'm not a PQ / M code expert.  Any help suggestions is greatly appreciated.  Thanks in advance!
 
PS - I've taken to writing my PowerQuery stuff in Visual Studio Code and it is a GREAT way to work!  Highly recommend - especially for newbies like me!
 
Cheer!
Chris
1 ACCEPTED SOLUTION
edhans
Super User III
Super User III

You can just use this formula @cmengel if I am reading your requirements correctly:

List.Contains({"A", "S"}, Text.Start([Column1], 1))

edhans_0-1624056316403.png

That returns a true or false if the text in column1 starts with an A or S, but not an R. So to make it part of your overall function:

#"AddedEXPENSE" =
        Table.AddColumn(
            AddedALLOWED,
            "EXPENSE",
            each
                if
        //  Explicitly define EXPENSE codes
                    List.Contains(
                        {
                            "3L",
                            "3K",
                            "3O",
                            // letter "oh" NOT ZERO!!!
                            "3A",
                            "3E",
                            "3G",
                            "3B",
                            "3F",
                            "3M",
                            "3S",
                            "3J",
                            "3H"
                        },
                        [WO_LABOR_CLASS_CODE]
                    )
                then
                    "Y"
        //  Explicitly define NON-EXPENSE codes
                else if
                List.Contains(
                        {
                            "3C",
                            "3I",
                            "3V",
                            "3P",
                            "3Q",
                            "3N",
                            "3W",
                            "3X"
                        },
                        Text.Start([WO_LABOR_CLASS_CODE], 2)
					)
                then
                    "N"
                else if
                    [WO_LABOR_CLASS_CODE] = "NON_LABOR" then
                    "N"
        //  Catch items that are not explicitly defined or mapped
                else
                    "CLARIFY",
            type text
        ),

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

View solution in original post

6 REPLIES 6
edhans
Super User III
Super User III

You can just use this formula @cmengel if I am reading your requirements correctly:

List.Contains({"A", "S"}, Text.Start([Column1], 1))

edhans_0-1624056316403.png

That returns a true or false if the text in column1 starts with an A or S, but not an R. So to make it part of your overall function:

#"AddedEXPENSE" =
        Table.AddColumn(
            AddedALLOWED,
            "EXPENSE",
            each
                if
        //  Explicitly define EXPENSE codes
                    List.Contains(
                        {
                            "3L",
                            "3K",
                            "3O",
                            // letter "oh" NOT ZERO!!!
                            "3A",
                            "3E",
                            "3G",
                            "3B",
                            "3F",
                            "3M",
                            "3S",
                            "3J",
                            "3H"
                        },
                        [WO_LABOR_CLASS_CODE]
                    )
                then
                    "Y"
        //  Explicitly define NON-EXPENSE codes
                else if
                List.Contains(
                        {
                            "3C",
                            "3I",
                            "3V",
                            "3P",
                            "3Q",
                            "3N",
                            "3W",
                            "3X"
                        },
                        Text.Start([WO_LABOR_CLASS_CODE], 2)
					)
                then
                    "N"
                else if
                    [WO_LABOR_CLASS_CODE] = "NON_LABOR" then
                    "N"
        //  Catch items that are not explicitly defined or mapped
                else
                    "CLARIFY",
            type text
        ),

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

View solution in original post

That's pretty slick, Ed! 


I’m usually answering from my phone, which means the results are visualized only in my mind. You’ll need to use my answer to know that it works—but it will work!!
cmengel
Frequent Visitor

Thank you @edhans !  This worked perfectly!  Greatly appreciated.  Have an excellent day!

Glad to help @cmengel 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting
watkinnc
Solution Sage
Solution Sage

I would use this "else if" instead of the "or"s:

 

else if List.Contains({"A", "B", "C", "1", "2"}, Text.ToList(Text.Start([WO_LABOR_CLASS_CODE], 1))) then "N" else if...

 

--Nate

 

If you


I’m usually answering from my phone, which means the results are visualized only in my mind. You’ll need to use my answer to know that it works—but it will work!!
cmengel
Frequent Visitor

Hey, @watkinnc !  Thanks for the reply.  I found the Text.ToList function unneccessary in this case.

Appreciate you taking the time!

Helpful resources

Announcements
PBI_User Group Leader_768x460.jpg

Manage your user group events

Check out the News & Announcements to learn more.

MBAS on Demand

2021 Release Wave 2 Plan

Power Platform release plan for the 2021 release wave 2 describes all new features releasing from October 2021 through March 2022.

Get Ready for Power BI Dev Camp

Microsoft named a Leader in The Forrester Wave

Microsoft received the highest score of any vendor in both the strategy and current offering categories.

R2 (Green) 768 x 460px.png

Microsoft Dynamics 365 & Power Platform User Professionals

DynamicsCon is a FREE, 4 half-day virtual learning experience for 11,000+ Microsoft Business Application users and professionals.

Top Kudoed Authors