Identifying largest number in a column

doublej41

Board Regular
Joined
Mar 9, 2011
Messages
86
Hi All

I have 2 columns of data, column A is an incremental ID number and column B includes a product name. When the product name is selected from the drop down box in Column B, I would like column A to automatically show the next ID number in the sequence.

The image illustrates the columns to try and make sense of my query. What I would like to happen is when I select BC-125 in cell B6, for a formula to work out that the next ID number for BC125 is 004 and so on for BC-100 and BC-150.




Uploaded with ImageShack.us


Any suggestions will be greatly appreciated.

Thanks
 
Last edited:
Maybe what I am looking to isn't possible without the use of VBA.

Let me have another go at explaining the situation:

If you look again at the image in my first post. What I would like to do is select a product in cell B6 using the validation list that includes all products. Once a product is selected I want the next incremental ID number for that product entered into A1.

So for example, if I select BC-125 in cell B6, I would want cell A6 to show 004, however if I chose either BC-100 or BC-150 then I would want cell A6 to show 002.

Does this make more sense?
 
Upvote 0

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Try this:

<b>Excel 2010</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="25px" style="background-color: #DAE7F5" /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">Dog</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">ID</td><td style=";">Product</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">Cat</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">001</td><td style=";">Mouse</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">Lama</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">001</td><td style=";">Lama</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Mouse</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">002</td><td style=";">Mouse</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">001</td><td style=";">Cat</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">002</td><td style=";">Lama</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #BBB;border-top:none;text-align: center;background-color: #DAE7F5;color: #161120">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #BBB"><thead><tr style=" background-color: #DAE7F5;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">F2</th><td style="text-align:left">{=IF(<font color="Blue">G2="","",MAX(<font color="Red">IF(<font color="Green">$G$1:$G1=$G2,$F$1:$F1,0</font>)</font>)+1</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />

The formula in F2 is copied down as far as you are likely to have rows of data.

Sorry, I should make it clear that G2 downwards is filled with Validation based on a list of the objects in A1:A4. Note the problem with this approach compare to VBA is that the IDs are not static - eg if a value is deleted from column B then the IDs will reset for any other products that appear after the deleted value.
 
Last edited:
Upvote 0
Richard - this works a treat, thanks for you help.

Apologies again for the confusion - Thanks a lot for sticking with it.
 
Upvote 0

Forum statistics

Threads
1,225,156
Messages
6,183,227
Members
453,152
Latest member
ChrisMd

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