SOLVED

Excel form al for creating number list (1, 2, 3, 4) based on value in previous cell

Copper Contributor

I'm creating a list for golf balls sold for a golf ball drop.

First column will have number of golf balls purchased 

Next column will give the numbers of the golf balls. 

For example if they purchase 1 golf ball, Column A would have 1, and Column B would have 1

If the next person purchases 3 golf balls, Column A would have 3, Column B  would have 2, 3, 4

If the next person purchases 5 golf balls, Column A would have 5, Column B would have 5, 6, 7, 8, 9

and so on. Is there a formula for this? Column B would be based on what is in Column A, and what is in the cell above it in Column B.

11 Replies

@Lauren_Hofstetter21 

 

Assuming your first entry is in cell A2, enter this formula in cell B2, which will automatically expand as new entries are made in cells A3, A4, etc.:

=LET(
    ζ,A2:INDEX(A:A,MATCH(7^89,A:A)),
    BYROW(ζ,LAMBDA(ξ,
        TEXTJOIN(",",,SEQUENCE(ξ,,SUM(A2:ξ)-ξ+1)))
    )
)

 

@JosWoolley 

Amazing that worked!!! 

Now if you're really smart, for our employees they have to be assigned letters A, B, C , . . .AA, BB, CC, . . .AAA, BBB, CCC

Will it work for letters like that? 

Don't have as many employee sales so it might not be worth the trouble.

Can you just clarify with a new small example dataset with expected results?

Thanks
best response confirmed by mtarler (Silver Contributor)
Solution

@Lauren_Hofstetter21 

 

Thanks. This will work as far as 'XFD' - let me know if you'll need to go beyond that.

 

=LET(
    ζ,A2:INDEX(A:A,MATCH(7^89,A:A)),
        BYROW(ζ,LAMBDA(ξ,
            TEXTJOIN(",",,
                SUBSTITUTE(
                    ADDRESS(1,SEQUENCE(ξ,,SUM(A2:ξ)-ξ+1),4),1,""
                )
            )
        )
    )
)

 

Regards

 

I don't understand how this fits in. Is this instead of the above counting or for certain conditions or something else? As for your counting let me note that counting using letters only SHOULD go: A, B, C, ... , Y, Z, AA, AB, AC, ... and NOT AA, BB, ...
IF that is OK then there is a simple trick in excel to use the ADDRESS function to have Excel convert for you as long as a max of XFD (i.e. 16384) is high enough. The trick is:
=SUBSTITUTE(ADDRESS(1,NNN,4),"1","")
Put any number (or reference to a number) in NNN and it will output the corresponding letters.

So w/r to the above equation here is it modified for letters:

=LET(
    ζ,A2:INDEX(A:A,MATCH(7^89,A:A)),
    BYROW(ζ,LAMBDA(ξ,
        TEXTJOIN(",",,SUBSTITUTE(ADDRESS(1,SEQUENCE(ξ,,SUM(A2:ξ)-ξ+1),4),"1","")))
    )
)
You amaze me, I'm only self taught in Excel, and have learned a lot but this is much appreciated!
Lauren you are welcome but it looks like @JosWoolley had you covered.
@JosWoolley , I didn't mean to essentially repeat your same answer but I swear when I posted my reply your reply wasn't there. Sometimes this board (or maybe my computer) does funny things
Not at all, your input is most appreciated! I've been working on forums long enough that I've seen so many examples of 'post crossover' that it's really not a surprise, nor an issue.

Cheers
1 best response

Accepted Solutions
best response confirmed by mtarler (Silver Contributor)
Solution

@Lauren_Hofstetter21 

 

Thanks. This will work as far as 'XFD' - let me know if you'll need to go beyond that.

 

=LET(
    ζ,A2:INDEX(A:A,MATCH(7^89,A:A)),
        BYROW(ζ,LAMBDA(ξ,
            TEXTJOIN(",",,
                SUBSTITUTE(
                    ADDRESS(1,SEQUENCE(ξ,,SUM(A2:ξ)-ξ+1),4),1,""
                )
            )
        )
    )
)

 

Regards

 

View solution in original post