+ Reply to Thread
Results 1 to 3 of 3

Incremental count based on quantity

Hybrid View

  1. #1
    Registered User
    Join Date
    12-01-2009
    Location
    Ireland
    MS-Off Ver
    Excel 2007
    Posts
    8

    Incremental count based on quantity

    Could someone please help me with this formula.
    I need incremental count based on quantity.
    Thx
    Ray..

    I Have the following
    item qty
    test1item001 4
    test2item001 2
    test3item001 1

    But I want below.. Im not to pushed about the quantity field but I need to print the items.
    item qty
    test1item001 1
    test1item002 1
    test1item003 1
    test1item004 1
    test2item001 1
    test2item002 1
    test3item001 1

  2. #2
    Forum Expert Domski's Avatar
    Join Date
    12-14-2009
    Location
    A galaxy far, far away
    MS-Off Ver
    Darth Office 2010
    Posts
    3,950

    Re: Incremental count based on quantity

    Maybe:

    Sub test()
    
        Dim rngLoopRange As Range
        For Each rngLoopRange In Range("A2:A" & Range("A" & Rows.Count).End(xlUp).Row)
            With Range("D" & Rows.Count).End(xlUp).Offset(1, 0)
                .Value = rngLoopRange
                If rngLoopRange.Offset(0, 1) > 1 Then
                    .AutoFill Destination:=.Resize(rngLoopRange.Offset(0, 1), 1)
                End If
                .Resize(rngLoopRange.Offset(0, 1), 1).Offset(0, 1) = 1
            End With
        Next rngLoopRange
    
    End Sub
    Dom
    "May the fleas of a thousand camels infest the crotch of the person who screws up your day and may their arms be too short to scratch..."

    Use code tags when posting your VBA code: [code] Your code here [/code]

    Remember, saying thanks only takes a second or two. Click the little star to give some Rep if you think an answer deserves it.

  3. #3
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Incremental count based on quantity

    With formulas you can do it in a couple of steps.

    Say your list is in A2:B4, then in C4 add a helper column to cumulatively sum the quantities:

    =SUM(B$2:B2)
    copied down

    Then in a new column to get the right number of results:

    =IF(ROWS(A$2:A2)>$C$4,"",LEFT(INDEX($A$2:$A$4,MIN(IF(ROWS(A$2:A2)<=$C$2:$C$4,ROW($A$2:$A$4)-ROW($A$2)+1))),LEN(INDEX($A$2:$A$4,MIN(IF(ROWS(A$2:A2)<=$C$2:$C$4,ROW($A$2:$A$4)-ROW($A$2)+1))))-3))
    confirmed with CTRL+SHIFT+ENTER not just ENTER and copy down

    Then in an adjacent column and assuming you put the above starting in E2:

    =E2&TEXT(COUNTIF(E$2:E2,E2),"000")
    entered with ENTER and copy down to get final results.
    Attached Files Attached Files
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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