Page 1 of 2 12 LastLast
Results 1 to 15 of 17
  1. #1
    3 Star Lounger
    Join Date
    Nov 2011
    Location
    Australia
    Posts
    221
    Thanks
    80
    Thanked 3 Times in 2 Posts

    Formula to Split data

    In the provided spreadsheet, Column B4 is a piece of data in it's "raw" form.
    In Cell Range C4 to F4 is the example if there was a folrmula to split what's in B4
    What is the Formula to split so it appears as I have shown please?
    I have already done my percent formula in G4 to claculate the percent of D4 and C4.
    And in H4 I add E4 and F4 then it's the percentage of C4.

    I would like those checked please if it's the correct formula to.

    Thanks
    Attached Files Attached Files

  2. #2
    Super Moderator RetiredGeek's Avatar
    Join Date
    Mar 2004
    Location
    Manning, South Carolina
    Posts
    9,434
    Thanks
    372
    Thanked 1,457 Times in 1,326 Posts
    XPDiHard,

    Here's some code that should do what I think you want. Just copy it into a standard module.
    To run the code select the 1st cell with your raw data { it will work its way down the sheet till it finds a blank row}.
    Press Alt+F8
    Click on DiceIt
    Click Run

    Code:
    Option Explicit
    
    Public Sub DiceIt()
    
         Dim lStartRow  As Long
         Dim lColCnt      As Long
         Dim lCurRow    As Long
         Dim vArr       As Variant
         
         lCurRow = ActiveCell.Row
         lStartRow = lCurRow
         
         Do While Cells(lCurRow, 2) <> ""
         
           vArr = Split(Cells(lCurRow, 2), "-")
           For lColCnt = 3 To 6
              Cells(lCurRow, lColCnt).Value = vArr(lColCnt - 3)
           Next lColCnt
           
           Cells(lCurRow, 7).FormulaR1C1 = "=R" & Format(lCurRow) & "C4/R" & _
                                                  Format(lCurRow) & "C3*100"
           Cells(lCurRow, 8).FormulaR1C1 = "=(R" & Format(lCurRow) & "C5+R" & _
                                                   Format(lCurRow) & "C6)/R" & _
                                                   Format(lCurRow) & "C3*100"
           lCurRow = lCurRow + 1
           
         Loop
         
         'Apply formatting
         Cells(lStartRow, 2).Select
         Range(Selection, Selection.End(xlToRight)).Select
         Selection.Copy
         Range(Selection, Selection.End(xlToRight)).Select
         Range(Selection, Selection.End(xlDown)).Select
         Selection.PasteSpecial Paste:=xlPasteFormats, Operation:=xlNone, _
             SkipBlanks:=False, Transpose:=False
         Application.CutCopyMode = False
         
    End Sub
    HTH
    XPDiHard-SPLIT AND PERCENT.xls
    May the Forces of good computing be with you!

    RG

    PowerShell & VBA Rule!

    My Systems: Desktop Specs
    Laptop Specs

  3. The Following User Says Thank You to RetiredGeek For This Useful Post:

    XPDiHard (2013-03-19)

  4. #3
    3 Star Lounger
    Join Date
    Nov 2011
    Location
    Australia
    Posts
    221
    Thanks
    80
    Thanked 3 Times in 2 Posts
    Thanks, works perfectly.
    The only minor tweak I included sheet select
    and instead of active cell, I specified the cell range

    Public Sub DiceIt()

    Sheets("Sheet2").Select

    Dim lStartRow As Long
    Dim lColCnt As Long
    Dim lCurRow As Long
    Dim vArr As Variant

    lCurRow = Sheets("Sheet2").Range("B4").Row
    ' lCurRow = ActiveCell.Row


    I previewd the post, don't know why it goes to Italics though.

  5. #4
    Bronze Lounger
    Join Date
    Jan 2001
    Location
    La Jolla, CA
    Posts
    1,470
    Thanks
    30
    Thanked 62 Times in 58 Posts
    Here's a non-VBA approach. Ugly, but works. :-)
    Attached Files Attached Files
    Last edited by kweaver; 2013-03-18 at 23:55.

  6. The Following User Says Thank You to kweaver For This Useful Post:

    XPDiHard (2013-03-19)

  7. #5
    Super Moderator RetiredGeek's Avatar
    Join Date
    Mar 2004
    Location
    Manning, South Carolina
    Posts
    9,434
    Thanks
    372
    Thanked 1,457 Times in 1,326 Posts
    XPDiHard,

    I previewd the post, don't know why it goes to Italics though.
    Try using [code] you're code here [/code] tags instead of the quote. HTH
    May the Forces of good computing be with you!

    RG

    PowerShell & VBA Rule!

    My Systems: Desktop Specs
    Laptop Specs

  8. The Following User Says Thank You to RetiredGeek For This Useful Post:

    XPDiHard (2013-03-19)

  9. #6
    WS Lounge VIP
    Join Date
    Mar 2002
    Location
    Newcazzle, UK
    Posts
    2,826
    Thanks
    136
    Thanked 482 Times in 459 Posts
    Hang on you lot.
    I haven't given my solution yet!

    See attached file.

    I used custom functions.
    So its a bit of vba and sheet formulas together.

    see sample rows 11 to 14, cells in column [C] to [F]

    In my version, as data in column [B] changes, the formulas will adjust automatically, rather than having to process the whole sheet.

    Now, as long as the data in column [B] is as described, my functions are nice and simple and easy to understand.
    And blimey, my formula for column [E] entries is a little shorter than the formula used in cell [E6].

    zeddy
    Attached Files Attached Files

  10. The Following User Says Thank You to zeddy For This Useful Post:

    XPDiHard (2013-03-19)

  11. #7
    Super Moderator RetiredGeek's Avatar
    Join Date
    Mar 2004
    Location
    Manning, South Carolina
    Posts
    9,434
    Thanks
    372
    Thanked 1,457 Times in 1,326 Posts
    XPDiHard / Zeddy,

    XPDiHard with your change
    Code:
    lCurRow = Sheets("Sheet2").Range("B4").Row
    ' lCurRow = ActiveCell.Row
    It will always process the entire sheet as Zeddy says. However, as it was originally programmed you could select any starting row, i.e. those that were recently added, and it would process from there down to the end.
    May the Forces of good computing be with you!

    RG

    PowerShell & VBA Rule!

    My Systems: Desktop Specs
    Laptop Specs

  12. The Following User Says Thank You to RetiredGeek For This Useful Post:

    XPDiHard (2013-03-19)

  13. #8
    Gold Lounger Maudibe's Avatar
    Join Date
    Aug 2010
    Location
    Pa, USA
    Posts
    2,637
    Thanks
    115
    Thanked 650 Times in 592 Posts
    Zeddy,

    I believe there is a slight error in one of your functions:

    error_array.jpg

    Code:
    Function split3(z)
    zData = z
    zSplit = Split(zData, "-")
    split3 = zSplit(3)
    End Function
    Should be:
    Code:
    Function split3(z)
    zData = z
    zSplit = Split(zData, "-")
    split3 = zSplit(2)
    End Function
    Maud

  14. The Following User Says Thank You to Maudibe For This Useful Post:

    XPDiHard (2013-03-19)

  15. #9
    3 Star Lounger
    Join Date
    Nov 2011
    Location
    Australia
    Posts
    221
    Thanks
    80
    Thanked 3 Times in 2 Posts
    Thanks all,
    I'll try them all and let know with another sample because this becomes part of a "bigger picture".
    There is more formulas after the percents.

  16. #10
    WS Lounge VIP
    Join Date
    Mar 2002
    Location
    Newcazzle, UK
    Posts
    2,826
    Thanks
    136
    Thanked 482 Times in 459 Posts
    Hi Maudibe

    Oops!
    You are too polite!
    What a plonk I am!
    That's what comes from quick copying the first function and then missing one of the required edits.

    I have attached the fixed file.

    zeddy
    Attached Files Attached Files

  17. The Following User Says Thank You to zeddy For This Useful Post:

    Maudibe (2013-03-20)

  18. #11
    WS Lounge VIP rory's Avatar
    Join Date
    Dec 2000
    Location
    Burwash, East Sussex, United Kingdom
    Posts
    6,280
    Thanks
    3
    Thanked 191 Times in 177 Posts
    If you always have 4 data items:
    Code:
    Public Sub DiceIt()
    
       Dim LastRow                As Long
    
       With Sheets("Sheet1")
          LastRow = .Cells(.Rows.Count, "B").End(xlUp).Row
          .Range("B4:B" & LastRow).TextToColumns Destination:=.Range("C4"), DataType:=xlDelimited, _
                                                 other:=True, otherchar:="-"
          .Range("G4:G" & LastRow).FormulaR1C1 = "=RC4/RC3*100"
          .Range("H4:H" & LastRow).FormulaR1C1 = "=(RC5+RC6)/RC3*100"
          .Range("B4:H4").Copy
          .Range("B4:H" & LastRow).PasteSpecial Paste:=xlPasteFormats, Operation:=xlNone, _
                                                SkipBlanks:=False, Transpose:=False
       End With
       Application.CutCopyMode = False
    
    End Sub
    Regards,
    Rory

    Microsoft MVP - Excel

  19. #12
    3 Star Lounger
    Join Date
    Nov 2011
    Location
    Australia
    Posts
    221
    Thanks
    80
    Thanked 3 Times in 2 Posts
    RetiredGeek and rory,
    I have put both macro in the same workbook for testing, plus I added some "Reset"
    conveniences for testing the project.

    I get errors in the formula after the macro is Run, if there are 0's ( zero's).

    I haven't tested the other replies yet, but will do so.

    And later on I do have a piece of macro somewhere, but in Column B3 to B32, if there is a 0, I will need
    to delete that entire row.



    Thanks all for your help so far.

    PS
    There will be another thread started once this part of the process is sorted, more formula to convert
    Column H to decimal and fractions in a certain way.
    Or do I keep the same project on this thread?
    Attached Files Attached Files

  20. #13
    WS Lounge VIP rory's Avatar
    Join Date
    Dec 2000
    Location
    Burwash, East Sussex, United Kingdom
    Posts
    6,280
    Thanks
    3
    Thanked 191 Times in 177 Posts
    What do you want the formulas to display if the data in column C is a 0? 0 or "" or some other message?

    For 0, use
    Code:
          .Range("G4:G" & LastRow).FormulaR1C1 = "=IF(RC3=0,0,RC4/RC3*100)"
          .Range("H4:H" & LastRow).FormulaR1C1 = "=IF(RC3=0,0,(RC5+RC6)/RC3*100)"
    Regards,
    Rory

    Microsoft MVP - Excel

  21. #14
    3 Star Lounger
    Join Date
    Nov 2011
    Location
    Australia
    Posts
    221
    Thanks
    80
    Thanked 3 Times in 2 Posts
    rory, the formula is fine.

    Only Cell C4 has the issue... Even when I tried deleting all columns C to H,
    Then I deleted Sheet2 and, Inserted a brand new Sheet.
    Cell C4 has a problem no matter what Format I tried.

    After the macro is Run, if I type in the same number in Cell C4, it's corrects itself.
    The #VALUE! becomes the calculation, in this case, 3.85

    It goes from 26 to 26.00 when 26 is typed, only that cell. !!

    This is not what I initially posting about, it's a new problem.
    Attached Files Attached Files

  22. #15
    WS Lounge VIP rory's Avatar
    Join Date
    Dec 2000
    Location
    Burwash, East Sussex, United Kingdom
    Posts
    6,280
    Thanks
    3
    Thanked 191 Times in 177 Posts
    There's a space in front of the text in C4 - that's what causes the problem.
    Regards,
    Rory

    Microsoft MVP - Excel

Page 1 of 2 12 LastLast

Posting Permissions

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