Batching data by groups with batch size limits

KPH679

New Member
Joined
Jun 4, 2014
Messages
5
Office Version
  1. 365
Platform
  1. Windows
Hi,

I have a table of data with approximately 5000 rows. I need to assign the same batch number to each row for an item list where another column changes its value occasionally, and may not be ordered (it can be if needed), but I need to limit the number of items in a batch to 500. The data in the Group column could be any text e.g. Time Zone

I am looking to achieve a very similar result to this thread, which gets most of the way there, but where it would increment the batch number if it reached a limit of the number of items in a batch e.g. 5 (but need to be able to change this limit by adjusting the value in the formula).

Item List | Group | Batch (limited to 5 items within a batch)
---------------|----------------|------------
Item 1 | Property A | 1
Item 2 | Property A | 1
Item 3 | Property A | 1
Item 4 | Property A | 1
Item 5 | Property A | 1
Item 6 | Property A | 2
Item 7 | Property A | 2
Item 8 | Property A | 2
Item 9 | Property B | 3
Item 10 | Property B | 3
Item 11 | Property A | 2
etc.

Appreciate the help!
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Hi,

I have a table of data with approximately 5000 rows. I need to assign the same batch number to each row for an item list where another column changes its value occasionally, and may not be ordered (it can be if needed), but I need to limit the number of items in a batch to 500. The data in the Group column could be any text e.g. Time Zone

I am looking to achieve a very similar result to this thread, which gets most of the way there, but where it would increment the batch number if it reached a limit of the number of items in a batch e.g. 5 (but need to be able to change this limit by adjusting the value in the formula).

Item List | Group | Batch (limited to 5 items within a batch)
---------------|----------------|------------
Item 1 | Property A | 1
Item 2 | Property A | 1
Item 3 | Property A | 1
Item 4 | Property A | 1
Item 5 | Property A | 1
Item 6 | Property A | 2
Item 7 | Property A | 2
Item 8 | Property A | 2
Item 9 | Property B | 3
Item 10 | Property B | 3
Item 11 | Property A | 2
etc.

Appreciate the help!

Clicked submit to soon. The answer that was provided by Eric W is this:

=IFERROR(IF(COUNTIF(A$2:A2,A2)=1,MAX(B$1:B1)+1,INDEX(B$2:B2,MATCH(A2,A$2:A2,0))),"")
 
Upvote 0
Can you post some sample data.

MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.

Also what version of Excel are you using?
I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)
 
Upvote 0
Like to have Auto BatchedItemCountry
1YNZIFLY20YHong Kong
1YNZIYKS02YHong Kong
1YNZIYKS32YHong Kong
1YNZIYKS32YHong Kong
1YNZIYKS20YHong Kong
2YNZIYKS23ZHong Kong
2YNYIYYZ04Hong Kong
2YNYIYZK33Hong Kong
2YNYIYZK32Hong Kong
2YNYITMY303Hong Kong
3Y637339YG2VW35Hong Kong
3Y637339YG2VW33Hong Kong
3Y637339YG2VW39Hong Kong
3Y637339YG2VW40Hong Kong
3Y637339YG2VW43Hong Kong
4Y605372JP6VW30Japan
5Y642435YG2VW03Australian Eastern
5Y642435YG2VW02Australian Eastern
5Y642435YG2VW03Australian Eastern
5Y625524HK2VW363Australian Eastern
5Y625524HK2VW364Australian Eastern
6Y625524HK2VW366Hong Kong
6Y625524HK2VW363Hong Kong
6Y625524HK2VW369Hong Kong
6EMYHK7YWYYT003YHong Kong
4JP6LYYVW20Japan
4JP6LYYVW23Japan
4JP6LYYVW900Japan
8JPNWJUMP03Australian Eastern
6Y609003YG3VW03Hong Kong
7Y609003YG3VW02Hong Kong
7YG3MOY32R2TM02Hong Kong
7YG3NETWORKTEYTHong Kong
7YRVLIJ03Hong Kong
7YRVLIJ02Hong Kong
8Y233439YY7UUY60Australian Eastern
8YY7HYNYNIFF03Australian Eastern
8YYYIFLY99Australian Eastern
8YYYIITX303Australian Eastern
etc.YYYIITX302Australian Eastern
YYYIWEY33Australian Eastern
YYYIWEY33Australian Eastern
YYUUIZTX33Australian Eastern
YYUUIZTX34Australian Eastern
YYUUITOM03Australian Eastern
YYUUITOM02Australian Eastern
YYUUIMGT60Australian Eastern
Y633356FR6VW03Central Europe
Y633356FR6VW04Central Europe
Y633356FR6VW05Central Europe
Y633356FR6VW07Central Europe
Y633356FR6VW03Central Europe
 
Upvote 0
Many thanks for that, how about
+Fluff 1.xlsm
ABC
1Like to have Auto BatchedItemCountry
21YNZIFLY20YHong Kong
31YNZIYKS02YHong Kong
41YNZIYKS32YHong Kong
51YNZIYKS32YHong Kong
61YNZIYKS20YHong Kong
72YNZIYKS23ZHong Kong
82YNYIYYZ04Hong Kong
92YNYIYZK33Hong Kong
102YNYIYZK32Hong Kong
112YNYITMY303Hong Kong
123Y637339YG2VW35Hong Kong
133Y637339YG2VW33Hong Kong
143Y637339YG2VW39Hong Kong
153Y637339YG2VW40Hong Kong
163Y637339YG2VW43Hong Kong
174Y605372JP6VW30Japan
185Y642435YG2VW03Australian Eastern
195Y642435YG2VW02Australian Eastern
205Y642435YG2VW03Australian Eastern
215Y625524HK2VW363Australian Eastern
225Y625524HK2VW364Australian Eastern
236Y625524HK2VW366Hong Kong
246Y625524HK2VW363Hong Kong
256Y625524HK2VW369Hong Kong
266EMYHK7YWYYT003YHong Kong
274JP6LYYVW20Japan
284JP6LYYVW23Japan
294JP6LYYVW900Japan
307JPNWJUMP03Australian Eastern
316Y609003YG3VW03Hong Kong
328Y609003YG3VW02Hong Kong
338YG3MOY32R2TM02Hong Kong
348YG3NETWORKTEYTHong Kong
358YRVLIJ03Hong Kong
368YRVLIJ02Hong Kong
377Y233439YY7UUY60Australian Eastern
387YY7HYNYNIFF03Australian Eastern
397YYYIFLY99Australian Eastern
407YYYIITX303Australian Eastern
419YYYIITX302Australian Eastern
429YYYIWEY33Australian Eastern
439YYYIWEY33Australian Eastern
449YYUUIZTX33Australian Eastern
459YYUUIZTX34Australian Eastern
4610YYUUITOM03Australian Eastern
4710YYUUITOM02Australian Eastern
4810YYUUIMGT60Australian Eastern
4911Y633356FR6VW03Central Europe
5011Y633356FR6VW04Central Europe
5111Y633356FR6VW05Central Europe
5211Y633356FR6VW07Central Europe
5311Y633356FR6VW03Central Europe
Main
Cell Formulas
RangeFormula
A2:A53A2=IF(MOD(COUNTIF(C$2:C2,C2)-1,5)=0,MAX(A$1:A1)+1,MAXIFS(A$1:A1,C$1:C1,C2))
 
Upvote 0
Solution
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,510
Messages
6,114,034
Members
448,543
Latest member
MartinLarkin

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