Consulting

Results 1 to 5 of 5

Thread: Sum less than 999

  1. #1

    Sum less than 999

    Hi all,

    I have a spreadsheet which I am trying to make more automated as we have to do this calculation once a day.

    Column A - Staff Numbers
    Column B - Code
    Column E - Miles

    Each Staff Number can have multiple rows from 1 - 100

    If like the below example a Staff Member has lots of miles. They have to be split into batches less than 999.

    The default CODE all the rows contain when i run this report is CVX. But for each time the number of miles goes above 999 the codes has to be changed to MIL1, if after splitting these if there is still more than 999 any remaining will go onto MIL2 and so on. (We have never come across one that goes above MIL4 if this helps make the code simpler)

    I hope i have explained this enough. Please see image below hopefully it will show what i mean.

    SEE EXAMPLE BELOW.



    Any help would be great

    Thanks
    Chris

  2. #2
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    [VBA]Public Sub ProcessData()
    Const TEST_COLUMN As String = "F" '<<<< change to suit
    Dim Lastrow As Long
    Dim Startrow As Long
    Dim nSum As Double
    Dim nCode As Long
    Dim i As Long

    Application.ScreenUpdating = False

    With ActiveSheet

    Startrow = 2
    Lastrow = .Cells(.Rows.Count, TEST_COLUMN).End(xlUp).Row
    For i = 2 To Lastrow

    If nSum + .Cells(i, TEST_COLUMN).Value <= 999 Then

    If nCode > 0 Then

    .Cells(i, "B").Value = "Mil" & nCode
    End If

    nSum = nSum + .Cells(i, TEST_COLUMN).Value
    Else

    nCode = nCode + 1
    .Cells(i, "B").Value = "Mil" & nCode
    nSum = .Cells(i, TEST_COLUMN).Value
    End If
    Next i
    End With

    Application.ScreenUpdating = True
    End Sub[/VBA]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  3. #3
    Perfect! Many thanks XLD!

  4. #4
    Would it be possible at the end for the macro to delete the rows with code CVX on. As these are already on the system

    Regards
    Chris

  5. #5
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    This should do it

    [VBA]Public Sub ProcessData()
    Const TEST_COLUMN As String = "F" '<<<< change to suit
    Dim Lastrow As Long
    Dim Endrow As Long
    Dim nSum As Double
    Dim nCode As Long
    Dim i As Long

    Application.ScreenUpdating = False

    With ActiveSheet

    Lastrow = .Cells(.Rows.Count, TEST_COLUMN).End(xlUp).Row
    For i = 2 To Lastrow

    If nSum + .Cells(i, TEST_COLUMN).Value <= 999 Then

    If nCode > 0 Then

    .Cells(i, "B").Value = "Mil" & nCode
    End If

    nSum = nSum + .Cells(i, TEST_COLUMN).Value
    Else

    nCode = nCode + 1
    .Cells(i, "B").Value = "Mil" & nCode
    nSum = .Cells(i, TEST_COLUMN).Value
    End If
    Next i

    Endrow = .Columns(2).Find("Mil1").Row - 1
    .Rows(2).Resize(Endrow - 1).Delete
    End With

    Application.ScreenUpdating = True
    End Sub[/VBA]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

Posting Permissions

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