happyhungarian

Active Member
Joined
Jul 19, 2011
Messages
252
Office Version
  1. 365
Platform
  1. Windows
Hi, I'm having difficulty getting a numbering scheme working correctly. I have a list of descriptions that I want to assign a number. If a certain description is used one time the number that gets assigned needs to be the same number that is used if that description shows up again later down the line. The following is an example description set, the formula used, the resulting "Numbering", and the issue highlighted. I need to do this all within the same column/cell but the problem is that this number is a subset of additional numbers so I can't have a trailing Vlookup to see if that description popped up before (because it will lookup the entire number not just this subset). I also can't have a separate reference section for a vlookup (which I was originally going to do).


DescriptionNumberingFormula for "Numbering"
A1SUMPRODUCT(1/COUNTIF(B$3:B3,B$3:B3&""))
B2SUMPRODUCT(1/COUNTIF(B$3:B4,B$3:B4&""))
C3SUMPRODUCT(1/COUNTIF(B$3:B5,B$3:B5&""))
C3SUMPRODUCT(1/COUNTIF(B$3:B6,B$3:B6&""))
C3SUMPRODUCT(1/COUNTIF(B$3:B7,B$3:B7&""))
4SUMPRODUCT(1/COUNTIF(B$3:B8,B$3:B8&""))<---"Blanks" accurately counted as a separate number
C4SUMPRODUCT(1/COUNTIF(B$3:B9,B$3:B9&""))<--- this should be "3"
D5SUMPRODUCT(1/COUNTIF(B$3:B10,B$3:B10&""))
E6SUMPRODUCT(1/COUNTIF(B$3:B11,B$3:B11&""))
C6SUMPRODUCT(1/COUNTIF(B$3:B12,B$3:B12&""))<--- this should be "3"

<tbody>
</tbody>
 
Last edited:

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
B​
C​
D​
2​
Description
Numbering
3​
A
1​
C3: =IF(COUNTIF(B$2:B2, B3), VLOOKUP(B3, $B$2:C2, 2, FALSE), SUMPRODUCT(1 / COUNTIF(B$3:B3, B$3:B3 & "")))
4​
B
2​
5​
C
3​
6​
C
3​
7​
C
3​
8​
4​
9​
C
3​
10​
D
5​
11​
E
6​
12​
C
3​
 
Upvote 0
So I came up with a trailing Vlookup with a find function. The number I'm having difficult with that I stated above is the second digit in the sequence. Here's the formula I used to calculate the first "1.1.1" sequence:

=A$1&"."&IFERROR(SUBSTITUTE(MID(SUBSTITUTE("." & VLOOKUP(B3,B$2:C2,2,FALSE)&REPT(" ",6),".",REPT(".",255)),2*255,255),".",""),SUMPRODUCT(1/COUNTIF(B$3:B3,B$3:B3&"")))&"."&COUNTIF($B$3:B3,B3)


Now the only problem I'm having is on BLANKS. The last row (1.6.0) should really be 1.4.1 since there was a preceeding BLANK. How can I change this to count blanks?



DescriptionNumbering
A1.1.1
B1.2.1
C1.3.1
C1.3.2
C1.3.3
1.4.0<---Accurately counts first blank as "4"
C1.3.4
D1.5.1
E1.6.1
C1.3.5
1.6.0<--- Should not be "6" should be "4"

<colgroup><col><col><col></colgroup><tbody>
</tbody>
 
Upvote 0
@shg thanks! That's the same solution I was thinking of but the only problem is the handling of blanks... it doesn't capture them correctly. It either needs to be "4" OR counted as it's own number (7) and then anything after that would see that there are two separate blanks.
 
Last edited:
Upvote 0
@marcelo branco... thanks but it looks like the formula errors out if there are two blanks... if you copy the formula into C13 it'll error rather than either assigning a new number or using the "4" from the previous blank
 
Last edited:
Upvote 0
Maybe...


B
C
1
2
Description​
Numbering​
3
A​
1​
4
B​
2​
5
C​
3​
6
C​
3​
7
C​
3​
8
4​
9
C​
3​
10
D​
5​
11
E​
6​
12
C​
3​
13
4​
14
D​
5​
15
E​
6​
16
4​
17
F​
7​

<tbody>
</tbody>


EDIT
Formula in C3 copied down
=IF(COUNTIF(B$3:B3,B3&"")=1,SUMPRODUCT(1/COUNTIF(B$3:B3,B$3:B3&"")),INDEX(C$2:C2,MATCH(B3&"",INDEX(B$2:B2&"",),0)))

M.
 
Last edited:
Upvote 0
For some reason when I enter it i still get an error on a second blank but your result on your table looks like it works perfect
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,654
Messages
6,120,758
Members
448,991
Latest member
Hanakoro

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top