+ Reply to Thread
Results 1 to 7 of 7

Separate string of text, based on dynamic 3-char, 4-char and spaces, into columns

Hybrid View

  1. #1
    Registered User
    Join Date
    10-16-2013
    Location
    Queensland, Australia
    MS-Off Ver
    MS365, Version 2202
    Posts
    73

    Separate string of text, based on dynamic 3-char, 4-char and spaces, into columns

    Long time, no post! everyone here taught me so well I didn't need help for a long time!

    I'm trying to export a 28-day roster to excel, however the software doesn't copy/paste well, nor does it export well, and the vendor is refusing to assist. I'll post an example of their software's output below. I can straight copy and paste, however, the data is pasted into column A, instead of remaining separated by date. However, I have a list of all possible roster codes, and, when pasting the data, is preserves days off as a single character space - one space is one day off, two consecutive spaces is two days off etc. Roster codes can be 3 or 4 characters long, and will have no breaks inbetween for consecutive shifts.

    Based of this information (the string of text, and the known roster codes, and the spaces), can I teach excel to separate out the string of text into separate columns? Examples of the data I have, and what I want it to look like, below.

    Data from roster UI/program

    Roster Data.JPG

    How it pastes into Excel

    Excel Data.JPG

    Desired output

    Desired output.JPG

    Example workbook attached.
    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 2406
    Posts
    44,662

    Re: Separate string of text, based on dynamic 3-char, 4-char and spaces, into columns

    Hi. Before we get going on this one...

    Is your forum profile showing the Excel PRODUCT that you need this request to work with?

    The best solutions often rely on knowing WHICH Office PRODUCT (Excel, NOT Windows) that you have. Please check that your forum profile is up-to-date. If you aren't sure, in Excel go to File/Account and report what it says below the MS logo at the top of that page. If your version is for Mac, please also state this.

    The three most recent Excel PRODUCTS are Excel 2019, Excel 2021 and MS365 - if you are using MS365, please give this name along with the Version number in your profile (e.g. MS365 (PC) Version 2211). The version number is in the About Excel section further down the Account page.

    Cheers,

    Glenn.
    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
    10-16-2013
    Location
    Queensland, Australia
    MS-Off Ver
    MS365, Version 2202
    Posts
    73

    Re: Separate string of text, based on dynamic 3-char, 4-char and spaces, into columns

    Hi Glenn! Product info is updated . The list of codes will have to wait till tonight - I’m not home at the moment.

  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 2406
    Posts
    44,662

    Re: Separate string of text, based on dynamic 3-char, 4-char and spaces, into columns

    If the roster codes were ALL 3 digits, it would hav ebeen reasonably easy. However, that IS an added complication!!

    You forgot to add a list of roster codes. Please do so.

    Another complication is that there is no space before the FIRST roster code.

    Does it look the same if you paste special as unicode text ??
    Last edited by Glenn Kennedy; 01-17-2023 at 09:15 PM.

  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 2406
    Posts
    44,662

    Re: Separate string of text, based on dynamic 3-char, 4-char and spaces, into columns

    OK. 2202 is a bit unhelpful... 2209 would have been better. However, I have an idea which might work. I'll know better when I see your code list.

  6. #6
    Forum Expert
    Join Date
    05-05-2015
    Location
    UK
    MS-Off Ver
    Microsoft Excel for Microsoft 365 MSO (Version 2402 Build 16.0.17328.20068) 64-bit
    Posts
    31,171

    Re: Separate string of text, based on dynamic 3-char, 4-char and spaces, into columns

    Sub Rotax()
    
    Dim ar, arr, b, c, d
    Sheets("Sheet1").Activate
    
    ar = [A1].CurrentRegion
    ReDim arr(1 To UBound(ar, 1), 1 To 30)
    wCard = Array("DG1", "MG9", "MGL", "VP6", "VP9")
    c = Range("Codes")
    n = 0
    For i = 1 To UBound(ar, 1)
        n = 1
        arr(i, n) = Left(ar(i, 1), 18)
        
        xstr = Trim(Mid(ar(i, 1), 19, 255))
        xstr = Replace(xstr, Chr(160), " ")  ' Replace Char(160) with blank
        xstr = Trim(xstr)                    ' Remove extraneous blanks
        xstr = Replace(xstr, " ", "*")       ' Replace blanks with "*"
        
        For j = 1 To UBound(c, 1)
            If Left(c(j, 1), 1) = "*" Then   ' Frre days
                cvalue = Replace(c(j, 1), "*", "X") & "|"  ' Replace "*" with "X" and add delimiter of "|"
            Else
                If Len(c(j, 1)) = 4 And c(j, 1) <> "OME1" Then                   ' Insert "?" into 3 position of 4 chaacter MG9 vs MG?O  (MG9O)
                   res = Application.Match(Left(c(j, 1), 3), wCard, 0)
                   cvalue = Left(c(j, 1), 2) & UCase(Chr(64 + res)) & Right(c(j, 1), 1)
                Else
                 cvalue = c(j, 1)
                End If
         End If
         xstr = Replace(xstr, c(j, 1), "|" & cvalue)       ' Replace code with replacement plus delimiter
       
        Next j
        
        
        d = Split(xstr, "|")      ' Split by delimiter
        For j = 0 To UBound(d, 1)
            If d(j) <> "" Then
                If Left(d(j), 1) = "X" Then  ' Indicates spaces
                    n = n + Len(d(j))        ' Increment "day" number
                    d(j) = ""                ' Set day to blank
                Else
                    n = n + 1
                End If
            arr(i, n) = Replace(Replace(Replace(Replace(Replace(d(j), "DGAO", "DG1O"), "MGBO", "MG9O"), "MGCO", "MGLO"), "VPDO", "VP6O"), "VPEO", "VP9O") '<<< needs coorection ??
           
            End If
        Next j
    
    Next i
    [A24].Resize(UBound(arr, 1), 30) = arr
    End Sub
    Attached Files Attached Files
    Last edited by JohnTopley; 01-18-2023 at 06:11 PM.
    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED.

  7. #7
    Registered User
    Join Date
    10-16-2013
    Location
    Queensland, Australia
    MS-Off Ver
    MS365, Version 2202
    Posts
    73

    Re: Separate string of text, based on dynamic 3-char, 4-char and spaces, into columns

    Sorry it took me so long to get the list of codes, I work in operating theatres these days, and can get called in for some very hectic shifts! Here 'tis:

    DF8O
    DG1O
    DE6
    DE1O
    DA1O
    DA8
    DA8O
    DA9
    DA9O
    DC1
    DC1O
    DC6
    DC6O
    DC8
    DC8O
    DC9
    DC9O
    DG6
    DG6O
    DJL
    DJLO
    DJM
    DJMO
    DL1
    DL1O
    DL8O
    DL9
    DL9O
    DLK
    DLL
    DLLO
    DJ9
    DJ9O
    DG7O
    DG8O
    DG9O
    DGK
    DGKO
    DGLO
    DGMO
    DJ1
    DJ1O
    DJ6
    DJ6O
    DJ7O
    DJ8O
    EA1O
    DO
    DE9
    VR6
    VR8
    VM6
    VM7
    VD8
    VL8
    VL6
    VL1
    VR1
    VR2
    VH1
    VH2
    VH8
    VH6
    VU8
    VS8
    VS6
    VU1
    VU2
    VU6
    VA8
    ME8
    DG8
    EC8
    EA8
    AA8T
    DGL
    DE8
    DEL
    FA8
    CA8
    ME9
    MJ9
    MC8
    MGL
    MG8
    DEM
    LJ9
    LA8
    LGMT
    LJ9T
    EC4
    OCZ
    TF8
    DL8
    DG7
    DG1
    DE1
    DGR
    DER
    DJ8
    LA9
    LGM
    EC9O
    EC9
    EC8O
    EC1O
    EC1
    ECJ
    ECJO
    ECM
    ECMO
    EE1
    EE1O
    EE6
    EAM
    EAMO
    DLM
    EA1
    EG8O
    EG6O
    EA6
    EA6O
    EA7
    EA7O
    EA8O
    EAL
    EALO
    MGLO
    MJ8O
    VH7
    VH9
    VHL
    VHM
    WP1
    WP8
    WP9
    MG6
    LE1
    LE1T
    LLL
    LLLT
    ME1
    ME1O
    ME8O
    ME9O
    MEL
    MELO
    MEM
    MEMO
    DA1
    DE6O
    DE7
    DE7O
    DE8O
    DEJ
    DEJO
    DEK
    DEKO
    DELO
    DEMO
    VN8
    VC8
    VP1
    VP6
    VP8
    VQ1
    VC6
    VQ8
    VN6
    VN1
    VF1
    VF6
    VF8
    VM1
    VM8
    VW8
    VW1
    WB1
    WB6
    WB8
    VA1
    VW6
    VS1
    VT1
    VT6
    VT8
    DG9
    MJ8
    MC9O
    MC8O
    DJ7
    DLH
    DJ80
    VC1
    E6
    XE8
    WGR
    VY8
    HS8
    HS1
    XG8
    XL8
    VU9
    FC8O
    MG8O
    WGRO
    MG9O
    MG9
    VLL
    WB9
    TJL
    OM2
    OE2
    EC5
    VSM
    VP9
    VS9
    VC9
    HLM
    HL9
    DF8
    HL8
    HD8
    HD1
    EJ8
    EJ6
    EGL
    EG8
    EG6
    EEL
    EE8
    VD1
    HS6
    HSL
    HS9
    HSM
    TF9
    XF9
    VS8L
    VYM
    VD9
    VP10
    VP8O
    VP9O
    VPM
    VMM

    Although it looks like John might have already solved my problem?! Thank you so much for the help John, I'm looking forward to play around with it on a day off (that I don't get called in on ) and making the thread as solved

+ 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. Replies: 12
    Last Post: 04-08-2014, 08:12 PM
  2. [SOLVED] Function to take text from x:th char to next n char
    By Temporary-Failure in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 10-07-2013, 02:19 AM
  3. [SOLVED] Edit Text String Based on 3rd Occurrence of Char
    By Camel in forum Excel General
    Replies: 4
    Last Post: 07-19-2012, 10:06 AM
  4. Convert 4 Char String to 4 Integer Columns
    By jtheis74 in forum Excel General
    Replies: 4
    Last Post: 10-05-2011, 11:19 AM
  5. RegExp to separate Upper from Lower Case Char In String
    By bdb1974 in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 06-17-2011, 12:31 PM
  6. Changing a single Char in a string to another ASCII char
    By goofy78270 in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 10-15-2007, 09:45 AM
  7. Replies: 6
    Last Post: 03-10-2006, 01:15 PM

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