cleaning up data in PowerQuery

SOQLee

Board Regular
Joined
Mar 18, 2015
Messages
58
Office Version
  1. 365
Platform
  1. Windows
I have a column in PQ that needs cleaning up. I'ld like to keep values that end with a combination of 1-letter and 4-digits.

Keep this pattern: ...A1234

Filter out this value pattern: ...A123

Help is appreciated. Thank you.
 

Excel Facts

Can you AutoAverage in Excel?
There is a drop-down next to the AutoSum symbol. Open the drop-down to choose AVERAGE, COUNT, MAX, or MIN
Do you want it to end with one capital letter followed by 4 digits ?

Code:
let    
Source = Table.FromRecords( {[ID="A1234"], [ID="123456"], [ID="B98543"], [ID="A0122"], [ID="BB560"], [ID="TU2"]}, type table [ID=Text.Type] ),
    
    fnSpecialFilter = (S as any) as logical =>
        let
            Txt = Text.Reverse( Text.From( S ) ),
            Res = if
                     Text.Length (Txt) < 5
                  then
                      false
                  else
                      List.Accumulate( 
                            {0..3},
                            true,
                            (state, current) => List.Contains( {"0".."9"}, Text.Middle( Txt, current, 1) ) and state
                      ) and List.Contains( {"A".."Z"}, Text.Middle( Txt, 4, 1) )
         in
            Res,
                      
     FinalTable = Table.SelectRows( Source, each fnSpecialFilter( [ID] ) )
                          
           
 in
    FinalTable
 
Last edited:
Upvote 0
Whoops.
Meant to say, this adds a new column that you can filter to "True" to pick out any text ending with a letter [a-z,A-Z] then 4 digit number
Code:
let Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each (Value.FromText(Text.Range([Column1], Text.Length([Column1])-4,4)) is number) and (Text.Range([Column1], Text.Length([Column1])-5, 1)=Text.Select(Text.Range([Column1], Text.Length([Column1])-5, 1),{"a".."z","A".."Z"} )))
in
#"Added Custom"
 
Upvote 0
The pattern I want keep is any value that is a combination of 2 letters followed by 4 numbers, ie. AA1234.
 
Upvote 0
Code:
let Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each (Value.FromText(Text.Range([Column1], Text.Length([Column1])-4,4)) is number) and (Text.Select(Text.Range([Column1], Text.Length([Column1])-5, 1),{"a".."z","A".."Z"} )<>"") and (Text.Select(Text.Range([Column1], Text.Length([Column1])-6, 1),{"a".."z","A".."Z"} )<>""))
in #"Added Custom"
 
Upvote 0

Forum statistics

Threads
1,213,526
Messages
6,114,122
Members
448,550
Latest member
CAT RG

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top