+ Reply to Thread
Results 1 to 10 of 10

Removing the last part of an ID from when it starts with a letter at the end.

  1. #1
    Forum Contributor
    Join Date
    05-09-2019
    Location
    South West
    MS-Off Ver
    365
    Posts
    108

    Removing the last part of an ID from when it starts with a letter at the end.

    Hi all.

    I was wondering if someone might be able to help.

    I have a list of product ID’s, some of which end in codes which I need to remove. These codes can will be a mix of letters and numbers (but it will always be a letter and then any numbers).

    What I need to do is strip out the last part of the code, starting from when there is a letter after a set of numbers (i.e. the product codes can sometimes start with a letter, then be followed by a series of numbers, and then the additional code would be a letter and possibly some numbers).

    e.g. if you had a code of 123RS, I need just 123. If I had a code of T123R2, I need just T123. If I had the code of ER123QZ I would need just ER123 etc.



    I’ve included an example of the types of code formats I have and the output I’m looking to achieve, but I’m not sure how I go about this and would much welcome any ideas!

    Many thanks
    Attached Files Attached Files

  2. #2
    Forum Moderator alansidman's Avatar
    Join Date
    02-02-2010
    Location
    Steamboat Springs, CO
    MS-Off Ver
    MS Office 365 Version 2405 Win 11 Home 64 Bit
    Posts
    23,882

    Re: Removing the last part of an ID from when it starts with a letter at the end.

    A fairly simple process if you are willing to use Power Query. Split your column on the delimiter Number to Non-Number

    Please Login or Register  to view this content.
    Power Query is a free AddIn for Excel 2010 and 2013, and is built-in functionality from Excel 2016 onwards (where it is referred to as "Get & Transform Data").

    It is a powerful yet simple way of getting, changing and using data from a broad variety of sources, creating steps which may be easily repeated and refreshed. I strongly recommend learning how to use Power Query - it's among the most powerful functionalities of Excel.

    - Follow this link to learn how to install Power Query in Excel 2010 / 2013.

    - Follow this link for an introduction to Power Query functionality.

    - Follow this link for a video which demonstrates how to use Power Query code provided.
    Attached Files Attached Files
    Alan עַם יִשְׂרָאֵל חַי


    Change an Ugly Report with Power Query
    Database Normalization
    Complete Guide to Power Query
    Man's Mind Stretched to New Dimensions Never Returns to Its Original Form

  3. #3
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,036

    Re: Removing the last part of an ID from when it starts with a letter at the end.

    Formula solution. This works on my version of Excel. It may work on yours, but will need to be entered as an array formula.

    These are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see the curly brackets { } appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...

    =IFERROR(LEFT(A2,SUM((CODE(MID($A2,ROW(INDIRECT("2:"&LEN($A2))),1))>=65)*(CODE(MID($A2,ROW(INDIRECT("1:"&LEN($A2)-1)),1))<65)*ROW(INDIRECT("2:"&LEN(A2))))-1),A2)
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  4. #4
    Forum Expert
    Join Date
    12-14-2012
    Location
    London England
    MS-Off Ver
    MS 365 Office Suite.
    Posts
    8,448

    Re: Removing the last part of an ID from when it starts with a letter at the end.

    Formula for B2 entered using Ctrl Shift Enter:

    =IF(ISNUMBER(MID(A2,2,99)*1),A2,LEFT(A2,MIN(TRANSPOSE(IF(ISNUMBER(MID(A2,ROW(INDIRECT("A2:A"&LEN(A2))),1)*1)*1,999,ROW(INDIRECT("A2:A"&LEN(A2))))))-1))
    My General Rules if you want my help. Not aimed at any person in particular:

    1. Please Make Requests not demands, none of us get paid here.

    2. Check back on your post regularly. I will not return to a post after 4 days.
    If it is not important to you then it definitely is not important to me.

  5. #5
    Forum Moderator
    Join Date
    01-21-2014
    Location
    St. Joseph, Illinois U.S.A.
    MS-Off Ver
    Office 365 v 2403
    Posts
    13,406

    Re: Removing the last part of an ID from when it starts with a letter at the end.

    @ Glenn Kennedy.
    Nice one, Glenn.
    Dave

  6. #6
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,036

    Re: Removing the last part of an ID from when it starts with a letter at the end.

    Dave... I only managed it after watching your deft use of ROW +- INDIRECT, over several years, in all sorts of different ways...

  7. #7
    Forum Moderator
    Join Date
    01-21-2014
    Location
    St. Joseph, Illinois U.S.A.
    MS-Off Ver
    Office 365 v 2403
    Posts
    13,406

    Re: Removing the last part of an ID from when it starts with a letter at the end.

    Glenn thank you for the kind words.
    Your solution above inspired this one at my end.
    Formula: copy to clipboard
    Please Login or Register  to view this content.

  8. #8
    Forum Guru Bo_Ry's Avatar
    Join Date
    09-10-2018
    Location
    Thailand
    MS-Off Ver
    MS 365
    Posts
    7,211

    Re: Removing the last part of an ID from when it starts with a letter at the end.

    Please try

    =LEFT(A2)&-LOOKUP(0,-MID(A2,2,ROW(A$1:A$9)))
    Attached Files Attached Files

  9. #9
    Forum Contributor
    Join Date
    05-09-2019
    Location
    South West
    MS-Off Ver
    365
    Posts
    108

    Re: Removing the last part of an ID from when it starts with a letter at the end.

    thank you all so much for your time and help with this, these solutions have all worked perfectly each in their own way, so thank you !!

  10. #10
    Forum Moderator
    Join Date
    01-21-2014
    Location
    St. Joseph, Illinois U.S.A.
    MS-Off Ver
    Office 365 v 2403
    Posts
    13,406

    Re: Removing the last part of an ID from when it starts with a letter at the end.

    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED.

    Also, you may not be aware that you can thank those who have helped you by clicking the small star icon located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of those who helped.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. [SOLVED] Using IF statement to Pull Any Value That Starts with a Letter
    By BolognaMan in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 07-10-2019, 02:48 PM
  2. [SOLVED] Sum if cell value starts with the letter R
    By CakeMish in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 11-13-2015, 11:06 AM
  3. Replies: 1
    Last Post: 05-17-2013, 04:56 AM
  4. keep column if text starts with letter
    By dundo84 in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 03-21-2013, 08:27 PM
  5. Assign value for data that starts with a certain letter
    By Steve Bostwick in forum Excel General
    Replies: 4
    Last Post: 01-10-2011, 12:19 PM
  6. check if a Cell value starts with a Letter
    By vijay2482 in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 11-02-2009, 09:53 AM
  7. Replies: 2
    Last Post: 07-26-2005, 03:05 AM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1