SOLVED

Automatically inserting a sequential invoice number

Occasional Contributor

Hello everyone,

Currently I pay a company to print blank invoices with sequential numbers.

I am attempting to find a way to print a similar blank invoice (that I have created in excel) but on each copy i would like the invoice number to increase by one.  Is this possible to do without manually changing everyone? 

I do not totally understand the concept of Macro's, but I have a basic knowledge on how to attach one to my system if necessary 

7 Replies

@AJ-FLAME 

Let's say you want the invoice number in cell D1 on Sheet1.

 

Press Alt + F11 to activate the Visual Basic Editor.

Double-click ThisWorkbook under Microsoft Excel Objects in the Prpject Explorer pane on the left.

Copy the following code into ThisWorkbook:

Private Sub Workbook_Open()
    With Worksheets("Sheet1").Range("D1")
        .Value = .Value + 1
    End With
End Sub

Switch back to Excel.

Save the workbook as a macro-enabled workbook (*.xlsm).

You'll have to allow macros when you open it.

 

Each time you open the workbook, the invoice number will be increased by 1.

if I print multiple copies will each copy have a new number? or will the number only change when i reopen the file?
best response confirmed by AJ-FLAME (Occasional Contributor)
Solution

@AJ-FLAME 

The code that I posted will only run when you open the workbook.

As an alternative, remove the Workbook_Open code.

Then select Insert > Module in the Visual Basic Editor.

Copy the following code into the module:

Sub PrintInvoices()
    Dim i As Long
    Dim n As Long
    n = Val(InputBox("How many copies do you want to print?"))
    For i = 1 To n
        With Worksheets("Sheet1").Range("D1")
            .Value = .Value + 1
        End With
        Worksheets("Sheet1").PrintOut
    End With
End Sub

Running this macro will prompt you for the number of invoices to be printed. The invoice number will be incremented each time.

If you wish, you can assign the macro to a button on the sheet, or to a Quick Access Toolbar, or to a keyboard shortcut.

This is exactly what I was looking for....... Thank you so much!
I keep getting "compile error: End With without With" can you help?

@AJ-FLAME 

Sorry about that, it was air code.

Sub PrintInvoices()
    Dim i As Long
    Dim n As Long
    n = Val(InputBox("How many copies do you want to print?"))
    For i = 1 To n
        With Worksheets("Sheet1").Range("D1")
            .Value = .Value + 1
        End With
        Worksheets("Sheet1").PrintOut
    Next i
End Sub
I just tested it and it works perfectly, thanks so much for your help!