+ Reply to Thread
Results 1 to 8 of 8

Extract values from between characters

  1. #1
    Registered User
    Join Date
    07-20-2021
    Location
    Florida
    MS-Off Ver
    Office Pro 2016
    Posts
    8

    Extract values from between characters

    I building a sheet where I track BP data. I have the raw data in a standardized text format:
    tttt: Sys/Dia/HR: optional notes

    I'm trying to extract various parameters (Systolic, Diastolic, Heart rate) from said data into adjoining cells (don't care about the notes). I've had limited success with the first after hacking together formulas, but testing has encountered errors. For systolic, I've managed to get this far with data in A2:
    =MID(A2, SEARCH(": ", A2) + 2, SEARCH("/", A2, SEARCH("/", A2) + 1) - SEARCH("/", A2))

    I'm attaching a demo file. Any help would be appreciated.

    -- Bad Idea Fairy
    Attached Files Attached Files

  2. #2
    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,105

    Re: Extract values from between characters

    Still using Excel 2016??
    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

  3. #3
    Registered User
    Join Date
    07-20-2021
    Location
    Florida
    MS-Off Ver
    Office Pro 2016
    Posts
    8

    Re: Extract values from between characters

    Yes, it's what I have. I'll upgrade Office next time I upgrade my computer.

  4. #4
    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,105

    Re: Extract values from between characters

    OK. So this won't work (O365 only):

    =TEXTSPLIT(TEXTBEFORE(TEXTAFTER(SUBSTITUTE(A2&":"," ","/"),"/",1),":",1),"/")+0

    copied down. But this will:

    =FILTERXML("<A><B>"&SUBSTITUTE(SUBSTITUTE($A2&" ",": ","/"),"/","</B><B>")&"</B></A>","//B["&COLUMNS($F2:F2)+1&"]")

    Change the bit in red (careful with the $ signs) to whichever cell you paste it into... F2 in the attached file. This is an array formula and needs to be set by pressing CTRL-SHIFT and Enter, together. it can then be dragged across and dnown without any further issue.
    Attached Files Attached Files

  5. #5
    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,105

    Re: Extract values from between characters

    A clearer explanation about array formulae.

    You seem to be using an older version of Excel than me. The formulae will be enclosed within a pair of { }.

    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...

  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,105

    Re: Extract values from between characters

    LoL. I forgot to highlight the red bit:

    =FILTERXML("<A><B>"&SUBSTITUTE(SUBSTITUTE($A2&" ",": ","/"),"/","</B><B>")&"</B></A>","//B["&COLUMNS($F2:F2)+1&"]")

  7. #7
    Registered User
    Join Date
    07-20-2021
    Location
    Florida
    MS-Off Ver
    Office Pro 2016
    Posts
    8

    Re: Extract values from between characters

    I've never heard of the FILTERXML formula, so I'll go research it.

    I was able to plug the formula into my original spreadsheet, tweak it for the specific cells I needed, and it works like a charm. Thanks for the help!

  8. #8
    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,105

    Re: Extract values from between characters

    You're welcome. FILTERXML is brilliant for parsing strings. BUT it falls over if it finds certain characters... like &. There are, however, workarounds if it finds a forbidden character and falls over.

+ 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] Extract characters inside a sting between specific characters
    By augr in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 03-12-2021, 07:04 PM
  2. [SOLVED] Extract unique values based on first 5 characters in the string
    By ABSTRAKTUS in forum Excel General
    Replies: 3
    Last Post: 10-14-2019, 10:03 AM
  3. [SOLVED] Extract values between Characters - Multiple occurences
    By aaron_burr in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 08-01-2019, 12:22 PM
  4. Extract values between characters
    By mifzal.mufthi in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 07-03-2018, 03:48 AM
  5. [SOLVED] Vlookup to extract last five characters or include only first 5 characters
    By Michael Lerena in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 05-10-2017, 04:53 PM
  6. [SOLVED] Extract left characters from string with exception of 2 right characters
    By sweetkel23 in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 09-16-2012, 10:45 PM
  7. [SOLVED] HOW DO I EXTRACT ALL CHARACTERS AFTER 5 CHARACTERS ON LEFT
    By GRYSYF in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 10-12-2005, 07: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