VBA to generate invoices from data base

joyrichter

New Member
Joined
Jun 17, 2023
Messages
31
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
Hi
Im getting stuck on a code, I have gotten the code to generate an invoice from a database worksheet, I want to copy the code for the complete sheet, to generate different invoices and to rename the generated invoices.
I will appreciate any tips and help.
Thank you
Joy
 
Hi @joyrichter

I coded the Macro from scratch, because your code had some errors/typos and added some "error" checking to it:
  • if the first cell (A2) contains no data, the macro will stop with a message
  • if a processed row contains a blank cell, the macro will stop with a message
  • if all rows have consistent data, the macro will start with a message
Here's the final result:

The table containing data:
MrExcel_joyrichter_invoice.xlsm
ABCDEFGHIJKLMNOP
1NameAdressCityProvincePostal CodeCountryVAT numberInvoice dateInvoice numberProduct codeDescriptionRateQtyDelivery distanceProduct Manager:Contact Number:
2Bela Bela Supermarket12 Church streetBela BelaLimpopo1001South Africa11223368112023/02/04ONC100CABanBanana89.131156Ms Tau084 321 1221
3Magalies Tea Garden3 Baber streetHartbeespoortNorth West6000South Africa11223368992023/02/04ONC101CATirTiramisu175.7679Ms Tau084 321 1221
4Klapoog's Castle89 Seahorse avenueLangebaanWestern Cape3001South Africa11223368662023/02/04ONC102CABanBanana89.1341471Ms Tau084 321 1221
5Klapoog's Castle89 Seahorse avenueLangebaanWestern Cape3001South Africa11223368662023/02/04ONC103CAPanPancakes78.2511471Ms Tau084 321 1221
6Mermaid Bakery123 Strand streetCape TownWestern Cape3000South Africa11223368552023/02/06ONC104CACrmCaramel16381420Ms Tau084 321 1221
7Jawsmunger5 Beach roadGqeberhaEastern Cape2000South Africa11223368442023/02/06ONC105CAFruFruit173.981068Ms Tau084 321 1221
8Mermaid Bakery123 Strand streetCape TownWestern Cape3000South Africa11223368552023/02/07ONC106CACrmCaramel16361420Ms Tau084 321 1221
9Waterfall Eatery34 Mossie avenueMbombelaMpumulanga5000South Africa11223368882023/02/07ONC107CACrtCarrot1639329Ms Tau084 321 1221
10Guppies56 Beach roadDurbanKwazulu Natal7000South Africa11223369102023/02/08ONC108CAChoChocolate1631573Ms Tau084 321 1221
11Roos Hotel31 Daisy avenueBloemfonteinFree State4000South Africa11223368772023/02/09ONC109CAPanPancakes78.259421Ms Tau084 321 1221
12Capricorn Inn51 Unicorn drivePolokwaneLimpopo1002South Africa11223368222023/02/09ONC110CAStrStrawberry1636309Ms Tau084 321 1221
13Klapoog's Castle89 Seahorse avenueLangebaanWestern Cape3001South Africa11223368662023/02/10ONC111CATirTiramisu175.791471Ms Tau084 321 1221
14Magalies Tea Garden3 Baber streetHartbeespoortNorth West6000South Africa11223368992023/02/11ONC112CABanBanana89.131079Ms Tau084 321 1221
15Guppies56 Beach roadDurbanKwazulu Natal7000South Africa11223369102023/02/13ONC113CAChoChocolate1633573Ms Tau084 321 1221
16Mermaid Bakery123 Strand streetCape TownWestern Cape3000South Africa11223368552023/02/14ONC114CARedRed velvet184.131420Ms Tau084 321 1221
17Klapoog's Castle89 Seahorse avenueLangebaanWestern Cape3001South Africa11223368662023/02/14ONC115CAOraOrange16361471Ms Tau084 321 1221
18Klapoog's Castle89 Seahorse avenueLangebaanWestern Cape3001South Africa11223368662023/02/16ONC116CAPanPancakes78.2571471Ms Tau084 321 1221
19Guppies56 Beach roadDurbanKwazulu Natal7000South Africa11223369102023/02/17ONC117CAStrStrawberry1636573Ms Tau084 321 1221
20UNISA student caféPreller streetPretoriaGauteng0001South Africa11223368332023/02/18ONC118CABanBanana89.13758Ms Tau084 321 1221
21Waterfall Eatery34 Mossie avenueMbombelaMpumulanga5000South Africa11223368882023/02/18ONC119CAChoChocolate1636329Ms Tau084 321 1221
22Roos Hotel31 Daisy avenueBloemfonteinFree State4000South Africa11223368772023/02/19ONC120CAOraOrange1637421Ms Tau084 321 1221
23Mermaid Bakery123 Strand streetCape TownWestern Cape3000South Africa11223368552023/02/20ONC121CATirTiramisu175.791420Ms Tau084 321 1221
24Magalies Tea Garden3 Baber streetHartbeespoortNorth West6000South Africa11223368992023/02/21ONC122CATirTiramisu175.7979Ms Tau084 321 1221
25UNISA student caféPreller streetPretoriaGauteng0001South Africa11223368332023/02/21ONC123CACrmCaramel163258Ms Tau084 321 1221
26Lulu's Bakery321 Justice streetPretoriaGauteng0001South Africa11223367892023/02/22ONC124CAChoChocolate163658Ms Tau084 321 1221
27Jawsmunger5 Beach roadGqeberhaEastern Cape2000South Africa11223368442023/02/25ONC125CACrtCarrot16341068Ms Tau084 321 1221
28Capricorn Inn51 Unicorn drivePolokwaneLimpopo1002South Africa11223368222023/02/26ONC126CAChoChocolate1638309Ms Tau084 321 1221
29UNISA student caféPreller streetPretoriaGauteng0001South Africa11223368332023/02/27ONC127CACrtCarrot163558Ms Tau084 321 1221
30Mermaid Bakery123 Strand streetCape TownWestern Cape3000South Africa11223368552023/02/27ONC128CARedRed velvet184.161420Ms Tau084 321 1221
31Lulu's Bakery321 Justice streetPretoriaGauteng0001South Africa11223367892023/02/28ONC129CAStrStrawberry163158Ms Tau084 321 1221
32Sophia's Tea Garden45 Tau avenueJohannesburgGauteng0002South Africa11223368002023/02/28ONC130CALemLemon Meringue173.9719Ms Tau084 321 1221
Recorded_Sales


the template table:
MrExcel_joyrichter_invoice.xlsm
ABCDEFGHIJKL
11
22Ikhishi Likagogo (Pty) LtdIsando
33086 121 4311Gauteng
4434
55South Africa
6VAT number: 99123456781
7
8Customer Name:Invoice date:Tax invoice number:Amount due (ZAR)
90
10
11Due dute:
12
13
14
15
16
17
18CodeDescriptionRateQty/DistTotal
19Product Rate / Quantity0
20Delivery Rate / Distance0
21Subtotal0
22VAT (15%)0
23Total0
24
25For any queries please contact the product manager. Details are provided below:
26Product Manager:
27Contact Number:
28
29Delivery:
30Delivery is charged at R2.07 (VAT inclusive) for delivery in South Africa.
Invoice_Template
Cell Formulas
RangeFormula
J9J9=L23
L19:L20L19=I19*J19
L21,L23L21=L19+L20
L22L22=L21*0.15



the VBA code:
VBA Code:
'Invoice Generator
Sub To_Generate_Invoices()

'Constant declaration
Const deliveryRate = 1.8

'Variable declaration:
Dim RecordedSalesWS As Worksheet
Dim InvoiceTemplateWS As Worksheet
Dim currentWorkingWS As Worksheet
Dim customerName As String
Dim customerAddress As String
Dim customerCity As String
Dim customerProvince As String
Dim customerPostalCode As Single
Dim customerCountry As String
Dim customerVATnumber As String
Dim invoiceDate As Date
Dim TaxinvoiceNumber As String
Dim productCode As String
Dim productDescription As String
Dim productRate As Single
Dim productQuantity As Integer
Dim deliveryDistance As Integer
Dim productionManager As String
Dim contactNumber As String
Dim rng_dest As Range
Dim rng As Range
Dim i As Long
Dim numberOfDatasets As Long
Dim numberOfInconsistentRows As Long
Dim dataInconsistency As Boolean

'Set workbook variables to worksheets
Set RecordedSalesWS = ThisWorkbook.Sheets("Recorded_Sales")
Set InvoiceTemplateWS = ThisWorkbook.Sheets("Invoice_Template")

Set rng_dest = ThisWorkbook.Sheets("Recorded_Sales").Range("A:P")
numberOfDatasets = 0
numberOfInconsistentRows = 0
dataInconsistency = False

'search for last row with data and check consistency (blank cells)
i = 2
numberOfInconsistentRows = 0
Do While rng_dest.Cells(i, 1) <> ""
   'loop through columns A to P (column 1 - 16), look for and count blank cells
   For j = 1 To 16
      If rng_dest.Cells(i, j).Value = "" Then numberOfInconsistentRows = numberOfInconsistentRows + 1
   Next j
   If numberOfInconsistentRows > 0 Then
      dataInconsistency = True
   End If
   numberOfInconsistentRows = 0
   i = i + 1
   numberOfDatasets = numberOfDatasets + 1
Loop
If numberOfDatasets = 0 Then
   MsgBox "No data detected in first row. Macro will stop."
   Exit Sub
End If
If dataInconsistency = True Then
   MsgBox "Inconsistent data. Please check for blank cells. Macro will stop"
   Exit Sub
End If
MsgBox numberOfDatasets & " Datasets found." & vbCrLf & "Generating invoices."

Application.ScreenUpdating = False
'write data to invoice template
For i = 1 To numberOfDatasets
   customerName = RecordedSalesWS.Range("A" & i + 1).Value
   customerAddress = RecordedSalesWS.Range("B" & i + 1).Value
   customerCity = RecordedSalesWS.Range("C" & i + 1).Value
   customerProvince = RecordedSalesWS.Range("D" & i + 1).Value
   customerPostalCode = RecordedSalesWS.Range("E" & i + 1).Value
   customerCountry = RecordedSalesWS.Range("F" & i + 1).Value
   customerVATnumber = RecordedSalesWS.Range("G" & i + 1).Value
   invoiceDate = RecordedSalesWS.Range("H" & i + 1).Value
   TaxinvoiceNumber = RecordedSalesWS.Range("I" & i + 1).Value
   productCode = RecordedSalesWS.Range("J" & i + 1).Value
   productDescription = RecordedSalesWS.Range("K" & i + 1).Value
   productRate = RecordedSalesWS.Range("L" & i + 1).Value
   productQuantity = RecordedSalesWS.Range("M" & i + 1).Value
   deliveryDistance = RecordedSalesWS.Range("N" & i + 1).Value
   productionManager = RecordedSalesWS.Range("O" & i + 1).Value
   contactNumber = RecordedSalesWS.Range("P" & i + 1).Value

   InvoiceTemplateWS.Copy After:=Sheets(Sheets.Count)
   On Error Resume Next
   ActiveSheet.Name = TaxinvoiceNumber
   On Error GoTo 0
  
   Set currentWorkingWS = ThisWorkbook.Sheets(TaxinvoiceNumber)
   With currentWorkingWS
      .Range("A9").Value = customerName
      .Range("A10").Value = customerAddress
      .Range("A11").Value = customerCity
      .Range("A12").Value = customerProvince
      .Range("A13").Value = customerPostalCode
      .Range("A13").NumberFormat = "0000"
      .Range("A14").Value = customerCountry
      .Range("A15").Value = "VAT Number:" & customerVATnumber
      .Range("C9").Value = invoiceDate
      .Range("C12") = invoiceDate + 7
      .Range("E9").Value = TaxinvoiceNumber
      .Range("A19").Value = productCode
      .Range("B19").Value = productDescription
      .Range("I19").Value = productRate
      .Range("J19").Value = productQuantity
      .Range("I20").Value = deliveryRate
      .Range("J20").Value = deliveryDistance
      .Range("A20").Value = "Delivery:"
      .Range("B20").Value = deliveryDistance
      .Range("C20").Value = "km - Isando to " & customerCity
      .Range("C26").Value = productionManager
      .Range("C27").Value = contactNumber
   End With
Next i

Application.ScreenUpdating = True
End Sub
 
Upvote 0
Solution

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
Hi @joyrichter

I coded the Macro from scratch, because your code had some errors/typos and added some "error" checking to it:
  • if the first cell (A2) contains no data, the macro will stop with a message
  • if a processed row contains a blank cell, the macro will stop with a message
  • if all rows have consistent data, the macro will start with a message
Here's the final result:

The table containing data:
MrExcel_joyrichter_invoice.xlsm
ABCDEFGHIJKLMNOP
1NameAdressCityProvincePostal CodeCountryVAT numberInvoice dateInvoice numberProduct codeDescriptionRateQtyDelivery distanceProduct Manager:Contact Number:
2Bela Bela Supermarket12 Church streetBela BelaLimpopo1001South Africa11223368112023/02/04ONC100CABanBanana89.131156Ms Tau084 321 1221
3Magalies Tea Garden3 Baber streetHartbeespoortNorth West6000South Africa11223368992023/02/04ONC101CATirTiramisu175.7679Ms Tau084 321 1221
4Klapoog's Castle89 Seahorse avenueLangebaanWestern Cape3001South Africa11223368662023/02/04ONC102CABanBanana89.1341471Ms Tau084 321 1221
5Klapoog's Castle89 Seahorse avenueLangebaanWestern Cape3001South Africa11223368662023/02/04ONC103CAPanPancakes78.2511471Ms Tau084 321 1221
6Mermaid Bakery123 Strand streetCape TownWestern Cape3000South Africa11223368552023/02/06ONC104CACrmCaramel16381420Ms Tau084 321 1221
7Jawsmunger5 Beach roadGqeberhaEastern Cape2000South Africa11223368442023/02/06ONC105CAFruFruit173.981068Ms Tau084 321 1221
8Mermaid Bakery123 Strand streetCape TownWestern Cape3000South Africa11223368552023/02/07ONC106CACrmCaramel16361420Ms Tau084 321 1221
9Waterfall Eatery34 Mossie avenueMbombelaMpumulanga5000South Africa11223368882023/02/07ONC107CACrtCarrot1639329Ms Tau084 321 1221
10Guppies56 Beach roadDurbanKwazulu Natal7000South Africa11223369102023/02/08ONC108CAChoChocolate1631573Ms Tau084 321 1221
11Roos Hotel31 Daisy avenueBloemfonteinFree State4000South Africa11223368772023/02/09ONC109CAPanPancakes78.259421Ms Tau084 321 1221
12Capricorn Inn51 Unicorn drivePolokwaneLimpopo1002South Africa11223368222023/02/09ONC110CAStrStrawberry1636309Ms Tau084 321 1221
13Klapoog's Castle89 Seahorse avenueLangebaanWestern Cape3001South Africa11223368662023/02/10ONC111CATirTiramisu175.791471Ms Tau084 321 1221
14Magalies Tea Garden3 Baber streetHartbeespoortNorth West6000South Africa11223368992023/02/11ONC112CABanBanana89.131079Ms Tau084 321 1221
15Guppies56 Beach roadDurbanKwazulu Natal7000South Africa11223369102023/02/13ONC113CAChoChocolate1633573Ms Tau084 321 1221
16Mermaid Bakery123 Strand streetCape TownWestern Cape3000South Africa11223368552023/02/14ONC114CARedRed velvet184.131420Ms Tau084 321 1221
17Klapoog's Castle89 Seahorse avenueLangebaanWestern Cape3001South Africa11223368662023/02/14ONC115CAOraOrange16361471Ms Tau084 321 1221
18Klapoog's Castle89 Seahorse avenueLangebaanWestern Cape3001South Africa11223368662023/02/16ONC116CAPanPancakes78.2571471Ms Tau084 321 1221
19Guppies56 Beach roadDurbanKwazulu Natal7000South Africa11223369102023/02/17ONC117CAStrStrawberry1636573Ms Tau084 321 1221
20UNISA student caféPreller streetPretoriaGauteng0001South Africa11223368332023/02/18ONC118CABanBanana89.13758Ms Tau084 321 1221
21Waterfall Eatery34 Mossie avenueMbombelaMpumulanga5000South Africa11223368882023/02/18ONC119CAChoChocolate1636329Ms Tau084 321 1221
22Roos Hotel31 Daisy avenueBloemfonteinFree State4000South Africa11223368772023/02/19ONC120CAOraOrange1637421Ms Tau084 321 1221
23Mermaid Bakery123 Strand streetCape TownWestern Cape3000South Africa11223368552023/02/20ONC121CATirTiramisu175.791420Ms Tau084 321 1221
24Magalies Tea Garden3 Baber streetHartbeespoortNorth West6000South Africa11223368992023/02/21ONC122CATirTiramisu175.7979Ms Tau084 321 1221
25UNISA student caféPreller streetPretoriaGauteng0001South Africa11223368332023/02/21ONC123CACrmCaramel163258Ms Tau084 321 1221
26Lulu's Bakery321 Justice streetPretoriaGauteng0001South Africa11223367892023/02/22ONC124CAChoChocolate163658Ms Tau084 321 1221
27Jawsmunger5 Beach roadGqeberhaEastern Cape2000South Africa11223368442023/02/25ONC125CACrtCarrot16341068Ms Tau084 321 1221
28Capricorn Inn51 Unicorn drivePolokwaneLimpopo1002South Africa11223368222023/02/26ONC126CAChoChocolate1638309Ms Tau084 321 1221
29UNISA student caféPreller streetPretoriaGauteng0001South Africa11223368332023/02/27ONC127CACrtCarrot163558Ms Tau084 321 1221
30Mermaid Bakery123 Strand streetCape TownWestern Cape3000South Africa11223368552023/02/27ONC128CARedRed velvet184.161420Ms Tau084 321 1221
31Lulu's Bakery321 Justice streetPretoriaGauteng0001South Africa11223367892023/02/28ONC129CAStrStrawberry163158Ms Tau084 321 1221
32Sophia's Tea Garden45 Tau avenueJohannesburgGauteng0002South Africa11223368002023/02/28ONC130CALemLemon Meringue173.9719Ms Tau084 321 1221
Recorded_Sales


the template table:
MrExcel_joyrichter_invoice.xlsm
ABCDEFGHIJKL
11
22Ikhishi Likagogo (Pty) LtdIsando
33086 121 4311Gauteng
4434
55South Africa
6VAT number: 99123456781
7
8Customer Name:Invoice date:Tax invoice number:Amount due (ZAR)
90
10
11Due dute:
12
13
14
15
16
17
18CodeDescriptionRateQty/DistTotal
19Product Rate / Quantity0
20Delivery Rate / Distance0
21Subtotal0
22VAT (15%)0
23Total0
24
25For any queries please contact the product manager. Details are provided below:
26Product Manager:
27Contact Number:
28
29Delivery:
30Delivery is charged at R2.07 (VAT inclusive) for delivery in South Africa.
Invoice_Template
Cell Formulas
RangeFormula
J9J9=L23
L19:L20L19=I19*J19
L21,L23L21=L19+L20
L22L22=L21*0.15



the VBA code:
VBA Code:
'Invoice Generator
Sub To_Generate_Invoices()

'Constant declaration
Const deliveryRate = 1.8

'Variable declaration:
Dim RecordedSalesWS As Worksheet
Dim InvoiceTemplateWS As Worksheet
Dim currentWorkingWS As Worksheet
Dim customerName As String
Dim customerAddress As String
Dim customerCity As String
Dim customerProvince As String
Dim customerPostalCode As Single
Dim customerCountry As String
Dim customerVATnumber As String
Dim invoiceDate As Date
Dim TaxinvoiceNumber As String
Dim productCode As String
Dim productDescription As String
Dim productRate As Single
Dim productQuantity As Integer
Dim deliveryDistance As Integer
Dim productionManager As String
Dim contactNumber As String
Dim a As Long
Dim rng_dest As Range
Dim rng As Range
Dim i As Long
Dim j As Long
Dim n As Long
Dim Counter As String
Dim Val As Integer
Dim numberOfDatasets As Long
Dim numberOfInconsistentRows As Long
Dim dataInconsistency As Boolean

'Set workbook variables to worksheets
Set RecordedSalesWS = ThisWorkbook.Sheets("Recorded_Sales")
Set InvoiceTemplateWS = ThisWorkbook.Sheets("Invoice_Template")

Set rng_dest = ThisWorkbook.Sheets("Recorded_Sales").Range("A:P")
numberOfDatasets = 0
numberOfInconsistentRows = 0
dataInconsistency = False

'search for last row with data and check consistency (blank cells)
i = 2
numberOfInconsistentRows = 0
Do While rng_dest.Cells(i, 1) <> ""
   'loop through columns A to P (column 1 - 16), look for and count blank cells
   For j = 1 To 16
      If rng_dest.Cells(i, j).Value = "" Then numberOfInconsistentRows = numberOfInconsistentRows + 1
   Next j
   If numberOfInconsistentRows > 0 Then
      dataInconsistency = True
   End If
   numberOfInconsistentRows = 0
   i = i + 1
   numberOfDatasets = numberOfDatasets + 1
Loop
If numberOfDatasets = 0 Then
   MsgBox "No data detected in first row. Macro will stop."
   Exit Sub
End If
If dataInconsistency = True Then
   MsgBox "Inconsistent data. Please check for blank cells. Macro will stop"
   Exit Sub
End If
MsgBox numberOfDatasets & " Datasets found." & vbCrLf & "Generating invoices."

Application.ScreenUpdating = False
'write data to invoice template
For i = 1 To numberOfDatasets
   customerName = RecordedSalesWS.Range("A" & i + 1).Value
   customerAddress = RecordedSalesWS.Range("B" & i + 1).Value
   customerCity = RecordedSalesWS.Range("C" & i + 1).Value
   customerProvince = RecordedSalesWS.Range("D" & i + 1).Value
   customerPostalCode = RecordedSalesWS.Range("E" & i + 1).Value
   customerCountry = RecordedSalesWS.Range("F" & i + 1).Value
   customerVATnumber = RecordedSalesWS.Range("G" & i + 1).Value
   invoiceDate = RecordedSalesWS.Range("H" & i + 1).Value
   TaxinvoiceNumber = RecordedSalesWS.Range("I" & i + 1).Value
   productCode = RecordedSalesWS.Range("J" & i + 1).Value
   productDescription = RecordedSalesWS.Range("K" & i + 1).Value
   productRate = RecordedSalesWS.Range("L" & i + 1).Value
   productQuantity = RecordedSalesWS.Range("M" & i + 1).Value
   deliveryDistance = RecordedSalesWS.Range("N" & i + 1).Value
   productionManager = RecordedSalesWS.Range("O" & i + 1).Value
   contactNumber = RecordedSalesWS.Range("P" & i + 1).Value

   InvoiceTemplateWS.Copy After:=Sheets(Sheets.Count)
   On Error Resume Next
   ActiveSheet.Name = TaxinvoiceNumber
   On Error GoTo 0
  
   Set currentWorkingWS = ThisWorkbook.Sheets(TaxinvoiceNumber)
   With currentWorkingWS
      .Range("A9").Value = customerName
      .Range("A10").Value = customerAddress
      .Range("A11").Value = customerCity
      .Range("A12").Value = customerProvince
      .Range("A13").Value = customerPostalCode
      .Range("A13").NumberFormat = "0000"
      .Range("A14").Value = customerCountry
      .Range("A15").Value = "VAT Number:" & customerVATnumber
      .Range("C9").Value = invoiceDate
      .Range("C12") = invoiceDate + 7
      .Range("E9").Value = TaxinvoiceNumber
      .Range("A19").Value = productCode
      .Range("B19").Value = productDescription
      .Range("I19").Value = productRate
      .Range("J19").Value = productQuantity
      .Range("I20").Value = deliveryRate
      .Range("J20").Value = deliveryDistance
      .Range("A20").Value = "Delivery:"
      .Range("B20").Value = deliveryDistance
      .Range("C20").Value = "km - Isando to " & customerCity
      .Range("C26").Value = productionManager
      .Range("C27").Value = contactNumber
   End With
Next i

Application.ScreenUpdating = True
End Sub
Thank you very very much,
I will study and compater the code and try to understand where my errors were..
 
Upvote 1
Thank you very very much,
I will study and compater the code and try to understand where my errors were..
The marked solution has been changed accordingly. In your future questions, please mark the post as the solution that actually answered your question, instead of your feedback message as it will help future readers. No further action is required for this thread.
 
Upvote 0

Forum statistics

Threads
1,215,417
Messages
6,124,787
Members
449,188
Latest member
Hoffk036

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