autogenerate WO number

flyingfree

New Member
Joined
Mar 2, 2011
Messages
8
I need to autogenerate a number in a cell when other data in the row is filled out.

Sheet is basically:


Date Site Name several other columns of non relevant data Work Order Number


I need the WO number to be in the following format:


(4 digit site code)-1920-(next number for that site)


I have another sheet with a table in it that shows:


Site Name Site Code


How can I pull the site code from one sheet into the number based on the site name from a previous column entry then add in the fiscal year reference and a numerical count of Work orders for that site?


Thinking of adding a hidden column to change site name to site code then formula in the WO number column to read:

=”C2”,”-1920”,countifs(C:C,site code 1, C :C, site code 2)

Is that the correct use of the countif function? Is there an easier way? Perhaps a VB code with a variable that increases by one everytime the loop is run? We have over 25 site codes.

How can I easily convert the site name to a site code based on the table in the other sheet?
 

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
Hi Flyingfree,

Here I've got the Site Name/Site Code table in the same sheet (columns G and H) but not as a table (it can of course be on another sheet and in an Excel Table so it auto-extends and you can use Names instead of references).

When you enter a Site Name in column B then in column C it retrieves the Site Code from the table.

Column D makes the WO code along the lines of your suggested formula but please note the mix of absolute and relative addresses in the COUNTIF so you get an ascending count.

Cells C2 and D2 need to be copied and pasted down as far as the maximum row you'll ever use.

NOTE: This is a calculated WO so if you change the data in any previous rows then it recalculates the WO numbers.

BCDEFGH
1Site NameSite CodeWOSite NameSite Code
2S101010101-1920-0001S10101
3S202020202-1920-0001S20202
4S101010101-1920-0002S30303
5S101010101-1920-0003
6S202020202-1920-0002
7S101010101-1920-0004
8S101010101-1920-0005
9S101010101-1920-0006

<tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
C2=INDEX(Sheet1!$H$2:$H$30,MATCH(B2,Sheet1!$G$2:$G$30,0))
D2=IF(C2="","",C2&"-1920-"&TEXT(COUNTIFS($C$2:C2,C2),"0000"))

<tbody>
</tbody>

<tbody>
</tbody>
 
Upvote 0
INDEX...hmmm I shall have to look that command up, might come in handy another time. Thanks, I'll implement this and get back to you on the results.
 
Upvote 0

Forum statistics

Threads
1,213,549
Messages
6,114,261
Members
448,558
Latest member
aivin

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