Aug 12 2022 06:21 AM
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
Aug 12 2022 06:44 AM
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.
Aug 12 2022 06:56 AM
Aug 12 2022 07:12 AM
SolutionThe 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.
Aug 12 2022 07:14 AM
Aug 12 2022 10:19 AM
Aug 12 2022 12:24 PM
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
Aug 12 2022 12:34 PM
Sep 13 2023 01:34 PM
Is there a way to create a save as button that will save the filename as the invoice number? @HansVogelaar
Sep 13 2023 02:01 PM
Using a variation of the code in my previous reply (invoice number in D1 on Sheet1), you could run the following macro from another workbook. Just make sure the invoice workbook is the active workbook when you run the macro.
Sub SaveInvoices()
Dim i As Long
Dim n As Long
Dim p As String
n = Val(InputBox("How many copies do you want to print?"))
p = ActiveWorkbook.Path
If Right(p, 1) <> Application.PathSeparator Then
p = p & Application.PathSeparator
End If
For i = 1 To n
With Worksheets("Sheet1").Range("D1")
.Value = .Value + 1
ActiveWorkbook.SaveCopyAs p & "Invoice " & .Value & ".xlsx"
End With
Next i
End Sub
Jan 12 2024 12:03 PM
I am also trying to get an invoice template to have sequential numbering to add 1 each time it is opened from a template. I am using Office for Mac and have tried using the instructions you have and I continue to get an error.
Jan 12 2024 12:43 PM
Jan 16 2024 12:58 PM
@HansVogelaar This worked when I did the one where it changed every time we open the workbook but then I saw your code for printing copies in sequential order so I tried it but it isn't working for me, the printing option to print multiple copies of the invoice with sequential numbers is not coming up for me... what am I doing wrong?
Jan 16 2024 01:12 PM
Which macro is failing for you?
Jan 16 2024 01:26 PM
Jan 16 2024 02:59 PM
If you run the macro
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
you should see a prompt:
The code will then increment the number in cell D1 on Sheet1 and print that sheet.
If you want to use another sheet or another cell, adjust the code accordingly.
Mar 21 2024 12:09 AM
Jun 21 2024 06:19 PM
@HansVogelaar hi. What if i also want to protect the cell so manually changing the invoice number will not be allowed. the code below works fine but if i protect the cell it gives an error
Jun 22 2024 01:03 AM
Hi, I have posted 5 macros in this discussion. Which one are you referring to?
Jul 18 2024 09:46 PM
@HansVogelaar If I may ask, I have used your code and the results are good, but I would like to ask if I can change the number format starting from 0001 and incrementing by 1 each time I print.
Aug 12 2022 07:12 AM
SolutionThe 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.