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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
cmengel
Advocate II
Advocate II

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
Super User

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
Super User

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
Anonymous
Not applicable

That's pretty slick, Ed! 

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
Anonymous
Not applicable

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

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

Appreciate you taking the time!

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Kudoed Authors